!95 Add merging/spliting to interval partitioned table.

Merge pull request !95 from ddwolf/add_merging_splitting_to_interval_tables
This commit is contained in:
opengauss-bot
2020-08-13 15:07:38 +08:00
committed by Gitee
13 changed files with 1686 additions and 101 deletions

View File

@ -1171,7 +1171,7 @@ inline Const* CalcLowBoundary(const Const* upBoundary, Interval* intervalValue)
upBoundary->constbyval);
}
inline int ValueCmpLowBoudary(Const** partKeyValue, const RangeElement* partition, Interval* intervalValue)
int ValueCmpLowBoudary(Const** partKeyValue, const RangeElement* partition, Interval* intervalValue)
{
Assert(partition->isInterval);
Assert(partition->len == 1);

View File

@ -543,6 +543,8 @@ static void ATExecModifyRowMovement(Relation rel, bool rowMovement);
static void ATExecTruncatePartition(Relation rel, AlterTableCmd* cmd);
static void checkColStoreForExchange(Relation partTableRel, Relation ordTableRel);
static void ATExecExchangePartition(Relation partTableRel, AlterTableCmd* cmd);
static void UpdatePrevIntervalPartToRange(
Relation srcRel, Relation pgPartition, int srcPartIndex, const char* briefCmd);
static void ATExecMergePartition(Relation partTableRel, AlterTableCmd* cmd);
static void checkCompressForExchange(Relation partTableRel, Relation ordTableRel);
static void checkColumnForExchange(Relation partTableRel, Relation ordTableRel);
@ -573,7 +575,7 @@ static void checkValidationForExchange(Relation partTableRel, Relation ordTableR
static void finishIndexSwap(List* partIndexList, List* ordIndexList);
static Oid getPartitionOid(Relation partTableRel, const char* partName, RangePartitionDefState* rangePartDef);
static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd);
static void checkSplitPointForSplit(SplitPartitionState* splitPart, Relation partTableRel, int srcPartSeq);
static void checkSplitPointForSplit(SplitPartitionState* splitPart, Relation partTableRel, int srcPartIndex);
static void checkDestPartitionNameForSplit(Oid partTableOid, List* partDefList);
static List* getDestPartBoundaryList(Relation partTableRel, List* destPartDefList, List** listForFree);
static void freeDestPartBoundaryList(List* list1, List* list2);
@ -16199,12 +16201,7 @@ static void ATPrepMergePartition(Relation rel)
{
if (!RELATION_IS_PARTITIONED(rel)) {
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE), errmsg("can not merge partition against NON-PARTITIONED table")));
}
if (rel->partMap->type == PART_TYPE_INTERVAL) {
ereport(ERROR, (errcode(ERRCODE_OPERATE_NOT_SUPPORTED),
errmsg("can not merge partition against interval partitioned table")));
(errcode(ERRCODE_WRONG_OBJECT_TYPE), errmsg("can not merge partitions against NON-PARTITIONED table")));
}
}
@ -16214,11 +16211,6 @@ static void ATPrepSplitPartition(Relation rel)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE), errmsg("can not split partition against NON-PARTITIONED table")));
}
if (rel->partMap->type == PART_TYPE_INTERVAL) {
ereport(ERROR, (errcode(ERRCODE_OPERATE_NOT_SUPPORTED),
errmsg("can not split partition against interval partitioned table")));
}
}
/*
@ -16400,8 +16392,10 @@ static void UpdateIntervalPartToRange(Relation relPartition, Oid partOid, const
/* If anything changed, write out the tuple. */
if (dirty) {
heap_inplace_update(relPartition, parttup);
simple_heap_update(relPartition, &parttup->t_self, parttup);
CatalogUpdateIndexes(relPartition, parttup);
}
heap_freetuple_ext(parttup);
}
/* assume caller already hold AccessExclusiveLock on the partition being dropped
@ -17350,6 +17344,16 @@ static void mergePartitionHeapData(Relation partTableRel, Relation tempTableRel,
}
}
static void UpdatePrevIntervalPartToRange(Relation srcRel, Relation pgPartition, int srcPartIndex, const char* briefCmd)
{
RangePartitionMap *parts = reinterpret_cast<RangePartitionMap *>(srcRel->partMap);
for (int i = srcPartIndex - 1; i > 0; --i) {
if (parts->rangeElements[i].isInterval) {
UpdateIntervalPartToRange(pgPartition, parts->rangeElements[i].partitionOid, briefCmd);
}
}
}
/*
* MERGE partitions p1, p2...pn into partition px
* infact, pn is the same partition with px
@ -17370,8 +17374,10 @@ static void ATExecMergePartition(Relation partTableRel, AlterTableCmd* cmd)
Partition destPart = NULL;
Relation destPartRel = NULL;
bool renameTargetPart = false;
int curPartSeq = 0;
int prevPartSeq = -1;
bool needUpdateIntervalToRange = false;
int firstPartIndex = -1;
int curPartIndex = 0;
int prevPartIndex = -1;
int iterator = 0;
int partNum = 0;
Oid targetPartTablespaceOid = InvalidOid;
@ -17383,6 +17389,8 @@ static void ATExecMergePartition(Relation partTableRel, AlterTableCmd* cmd)
Relation tempTableRel = NULL;
ObjectAddress object;
TransactionId FreezeXid;
RangePartitionMap* partMap = reinterpret_cast<RangePartitionMap*>(partTableRel->partMap);
RangeElement* ranges = partMap->rangeElements;
srcPartitions = (List*)cmd->def;
destPartName = cmd->name;
@ -17438,16 +17446,28 @@ static void ATExecMergePartition(Relation partTableRel, AlterTableCmd* cmd)
}
/* from partitionoid to partition sequence */
curPartSeq = partOidGetPartSequence(partTableRel, srcPartOid);
curPartIndex = partOidGetPartSequence(partTableRel, srcPartOid) - 1;
/* check the continuity of sequence, not the first round loop */
if (iterator != 1) {
if (curPartSeq - prevPartSeq != 1)
if (curPartIndex - prevPartIndex != 1)
ereport(ERROR,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("source partitions must be continuous and in ascending order of boundary")));
if (ranges[curPartIndex].isInterval) {
// previous partition's upperBound should be equal with current partition's lowerBound
Const* prevUpper = ranges[prevPartIndex].boundary[0];
if (ValueCmpLowBoudary(&prevUpper, ranges + curPartIndex, partMap->intervalValue) != 0) {
ereport(ERROR,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("source partitions must be continuous and in ascending order of boundary")));
}
needUpdateIntervalToRange = true;
}
} else {
firstPartIndex = curPartIndex;
}
prevPartSeq = curPartSeq;
prevPartIndex = curPartIndex;
/* save the last source partition name */
if (iterator == partNum) {
@ -17630,12 +17650,22 @@ static void ATExecMergePartition(Relation partTableRel, AlterTableCmd* cmd)
/* swap the heap relfilenode */
mergePartitionHeapSwap(partTableRel, destPartOid, tempTableOid, FreezeXid);
CommandCounterIncrement();
/* free index list */
list_free_ext(index_list);
list_free_ext(clonedIndexRelId_list);
list_free_ext(indexDestPartOid_list);
const char* BRIEF_CMD_MERGE = "MERGE PARTITIONS";
if (needUpdateIntervalToRange) {
/* update previous partition and the new partition to range partition */
Relation pgPartition = relation_open(PartitionRelationId, RowExclusiveLock);
UpdatePrevIntervalPartToRange(partTableRel, pgPartition, firstPartIndex, BRIEF_CMD_MERGE);
/* update merge result partition to range partition */
UpdateIntervalPartToRange(pgPartition, destPartOid, BRIEF_CMD_MERGE);
relation_close(pgPartition, NoLock);
}
/* ensure that preceding changes are all visible to the next deletion step. */
CommandCounterIncrement();
@ -18946,7 +18976,7 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
RangePartitionMap* partMap = NULL;
Oid partTableOid = InvalidOid;
Oid srcPartOid = InvalidOid;
int srcPartSeq = -1;
int srcPartIndex = -1;
ListCell* cell = NULL;
int currentPartNum = 0;
int partKeyNum = 0;
@ -19021,8 +19051,8 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
}
// get src partition sequence
srcPartSeq = partOidGetPartSequence(partTableRel, srcPartOid);
if (srcPartSeq < 1) {
srcPartIndex = partOidGetPartSequence(partTableRel, srcPartOid) - 1;
if (srcPartIndex < 0) {
Assert(false);
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
@ -19030,16 +19060,14 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
srcPartOid,
splitPart->src_partition_name ? splitPart->src_partition_name : "NULL",
partTableRel->rd_id)));
} else {
--srcPartSeq;
}
bool isPrevInterval = srcPartIndex > 0 && partMap->rangeElements[srcPartIndex - 1].isInterval;
// if split point
if (PointerIsValid(splitPart->split_point)) {
RangePartitionDefState* rangePartDef = NULL;
// check split point value
checkSplitPointForSplit(splitPart, partTableRel, srcPartSeq);
checkSplitPointForSplit(splitPart, partTableRel, srcPartIndex);
Assert(list_length(destPartDefList) == 2);
@ -19051,7 +19079,7 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
* generate boundary for the second partititon
*/
rangePartDef = (RangePartitionDefState*)list_nth(destPartDefList, 1);
rangePartDef->boundary = getPartitionBoundaryList(partTableRel, srcPartSeq);
rangePartDef->boundary = getPartitionBoundaryList(partTableRel, srcPartIndex);
} else {
// not split point
int compare = 0;
@ -19067,11 +19095,15 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
destPartBoundaryList = getDestPartBoundaryList(partTableRel, destPartDefList, &listForFree);
// check the first dest partition boundary
if (srcPartSeq != 0) {
compare = comparePartitionKey(partMap,
partMap->rangeElements[srcPartSeq - 1].boundary,
(Const**)lfirst(list_head(destPartBoundaryList)),
partKeyNum);
if (srcPartIndex != 0) {
if (!partMap->rangeElements[srcPartIndex].isInterval) {
compare = comparePartitionKey(partMap, partMap->rangeElements[srcPartIndex - 1].boundary,
(Const**)lfirst(list_head(destPartBoundaryList)), partKeyNum);
} else {
Const** partKeyValue = (Const**)lfirst(list_head(destPartBoundaryList));
RangeElement& srcPartition = partMap->rangeElements[srcPartIndex];
compare = -ValueCmpLowBoudary(partKeyValue, &srcPartition, partMap->intervalValue);
}
if (compare >= 0) {
ereport(ERROR,
(errcode(ERRCODE_INVALID_OPERATION),
@ -19105,7 +19137,7 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
// check the last dest partition boundary equal the src partition boundary
compare = comparePartitionKey(partMap,
(Const**)lfirst(list_tail(destPartBoundaryList)),
partMap->rangeElements[srcPartSeq].boundary,
partMap->rangeElements[srcPartIndex].boundary,
partKeyNum);
if (compare != 0) {
ereport(ERROR,
@ -19117,7 +19149,12 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
// add dest partitions
fastAddPartition(partTableRel, destPartDefList, &newPartOidList);
freeDestPartBoundaryList(destPartBoundaryList, listForFree);
if (isPrevInterval) {
// modify all previous *interval* partitions to range partitions, *possibly* no such partitions
Relation pgPartition = relation_open(PartitionRelationId, RowExclusiveLock);
UpdatePrevIntervalPartToRange(partTableRel, pgPartition, srcPartIndex, "SPLIT PARTITION");
relation_close(pgPartition, NoLock);
}
#ifdef PGXC
if (IS_PGXC_DATANODE) {
#endif
@ -19167,7 +19204,7 @@ static void ATExecSplitPartition(Relation partTableRel, AlterTableCmd* cmd)
}
// check split point
static void checkSplitPointForSplit(SplitPartitionState* splitPart, Relation partTableRel, int srcPartSeq)
static void checkSplitPointForSplit(SplitPartitionState* splitPart, Relation partTableRel, int srcPartIndex)
{
RangePartitionMap* partMap = NULL;
ParseState* pstate = NULL;
@ -19176,7 +19213,6 @@ static void checkSplitPointForSplit(SplitPartitionState* splitPart, Relation par
int i = 0;
int partKeyNum = 0;
int compareSrcPart = 0;
int comparePrePart = 0;
// get partition key number
partMap = (RangePartitionMap*)partTableRel->partMap;
@ -19200,26 +19236,28 @@ static void checkSplitPointForSplit(SplitPartitionState* splitPart, Relation par
partKeyValueArr[i++] = (Const*)lfirst(cell);
}
// compare splint point with src partition
// compare split point with src partition
compareSrcPart =
comparePartitionKey(partMap, partKeyValueArr, partMap->rangeElements[srcPartSeq].boundary, partKeyNum);
// compare splint point with the previous partition of src partition
if (srcPartSeq == 0) {
comparePrePart = 1;
} else {
comparePrePart =
comparePartitionKey(partMap, partKeyValueArr, partMap->rangeElements[srcPartSeq - 1].boundary, partKeyNum);
}
// splint point should be between the previous partition and the src partition
if (comparePrePart <= 0) {
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("split point is too low")));
}
comparePartitionKey(partMap, partKeyValueArr, partMap->rangeElements[srcPartIndex].boundary, partKeyNum);
if (compareSrcPart >= 0) {
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("split point is too high")));
}
bool lowerOverflow = false;
if (partMap->rangeElements[srcPartIndex].isInterval) {
// compare split point with the lower boundary of src partition
RangeElement& srcPart = partMap->rangeElements[srcPartIndex];
Interval *interval = partMap->intervalValue;
lowerOverflow = !ValueSatisfyLowBoudary(&partKeyValueArr[0], &srcPart, interval, false);
} else {
// compare split point with the previous partition of src partition
if (srcPartIndex != 0) {
lowerOverflow = comparePartitionKey(
partMap, partKeyValueArr, partMap->rangeElements[srcPartIndex - 1].boundary, partKeyNum) <= 0;
}
}
if (lowerOverflow) {
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("split point is too low")));
}
}
static void checkDestPartitionNameForSplit(Oid partTableOid, List* partDefList)

View File

@ -363,5 +363,5 @@ extern Oid GetNeedDegradToRangePartOid(Relation rel, Oid partOid);
extern RangeElement* CopyRangeElementsWithoutBoundary(const RangeElement* src, int elementNum);
extern char* ReadIntervalStr(HeapTuple tuple, TupleDesc tupleDesc);
extern oidvector* ReadIntervalTablespace(HeapTuple tuple, TupleDesc tupleDesc);
int ValueCmpLowBoudary(Const** partKeyValue, const RangeElement* partition, Interval* intervalValue);
#endif /* PARTITIONMAP_GS_H_ */

View File

@ -396,28 +396,28 @@ INTERVAL('1 MONTH')
( PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
select relname, parentid, reltoastrelid, boundaries from pg_partition;
relname | parentid | reltoastrelid | boundaries
----------------+----------+---------------+------------------------------
interval_sales | 19348 | 0 |
p0 | 19348 | 19354 | {"Tue Jan 01 00:00:00 2008"}
p1 | 19348 | 19357 | {"Tue May 06 00:00:00 2008"}
select relname, case when reltoastrelid > 0 then 'TRUE' else 'FALSE' end as has_toastrelid, boundaries from pg_partition;
relname | has_toastrelid | boundaries
----------------+----------------+------------------------------
interval_sales | FALSE |
p0 | TRUE | {"Tue Jan 01 00:00:00 2008"}
p1 | TRUE | {"Tue May 06 00:00:00 2008"}
(3 rows)
insert into interval_sales values (generate_series(1,10), generate_series(1,10), generate_series(TO_DATE('2020-01-01', 'YYYY-MM-DD'),TO_DATE('2020-07-01', 'YYYY-MM-DD'),'1 day'), 1, 1, 1, 1);
select relname, parentid, reltoastrelid, boundaries from pg_partition;
relname | parentid | reltoastrelid | boundaries
----------------+----------+---------------+------------------------------
interval_sales | 19348 | 0 |
p0 | 19348 | 19354 | {"Tue Jan 01 00:00:00 2008"}
p1 | 19348 | 19357 | {"Tue May 06 00:00:00 2008"}
sys_p1 | 19348 | 19361 | {"Mon Jan 06 00:00:00 2020"}
sys_p2 | 19348 | 19365 | {"Thu Feb 06 00:00:00 2020"}
sys_p3 | 19348 | 19369 | {"Fri Mar 06 00:00:00 2020"}
sys_p4 | 19348 | 19373 | {"Mon Apr 06 00:00:00 2020"}
sys_p5 | 19348 | 19377 | {"Wed May 06 00:00:00 2020"}
sys_p6 | 19348 | 19381 | {"Sat Jun 06 00:00:00 2020"}
sys_p7 | 19348 | 19385 | {"Mon Jul 06 00:00:00 2020"}
select relname, case when reltoastrelid > 0 then 'TRUE' else 'FALSE' end as has_toastrelid, boundaries from pg_partition;
relname | has_toastrelid | boundaries
----------------+----------------+------------------------------
interval_sales | FALSE |
p0 | TRUE | {"Tue Jan 01 00:00:00 2008"}
p1 | TRUE | {"Tue May 06 00:00:00 2008"}
sys_p1 | TRUE | {"Mon Jan 06 00:00:00 2020"}
sys_p2 | TRUE | {"Thu Feb 06 00:00:00 2020"}
sys_p3 | TRUE | {"Fri Mar 06 00:00:00 2020"}
sys_p4 | TRUE | {"Mon Apr 06 00:00:00 2020"}
sys_p5 | TRUE | {"Wed May 06 00:00:00 2020"}
sys_p6 | TRUE | {"Sat Jun 06 00:00:00 2020"}
sys_p7 | TRUE | {"Mon Jul 06 00:00:00 2020"}
(10 rows)
drop table interval_sales;

View File

@ -0,0 +1,721 @@
-- 1 init environment
set DateStyle = 'Postgres';
prepare pg_partition_sql(char) as
select relname,
parttype,
rangenum,
intervalnum,
partstrategy,
interval,
to_char(to_date(boundaries[1], 'Dy Mon DD hh24:mi:ss YYYY'), 'YYYY-MM-DD') boundary
from pg_partition
where parentid = (select oid from pg_class where relname = $1)
order by to_date(boundaries[1], 'Dy Mon DD hh24:mi:ss YYYY');
-- A. Test without index
CREATE TABLE interval_sales
(
prod_id NUMBER(6),
cust_id NUMBER,
time_id DATE,
channel_id CHAR(1),
promo_id NUMBER(6),
quantity_sold NUMBER(3),
amount_sold NUMBER(10, 2)
)
PARTITION BY RANGE (time_id)
INTERVAL
('1 MONTH')
(PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
alter table interval_sales split partition p0 at (to_date('2007-02-10', 'YYYY-MM-DD')) into (partition p0_1, partition p0_2);
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p0_1 | p | 0 | 0 | r | | 2007-02-10
p0_2 | p | 0 | 0 | r | | 2008-01-01
p1 | p | 0 | 0 | r | | 2008-05-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(4 rows)
insert into interval_sales
values (1, 1, to_date('9-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('20-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('08-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-4-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-11-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-12-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-01-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-5-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-6-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-7-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
-- 2 cases
-- 2.1.0 merge normal range partitions in bad order
select *
from interval_sales partition (p0_1);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Fri Feb 09 00:00:00 2007 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (p0_2);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Feb 11 00:00:00 2007 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (p1);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Mon Feb 11 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales merge partitions p1, p0_1, p0_2 into partition p01;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.1.1 merge normal range partitions in right order
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p0_1 | p | 0 | 0 | r | | 2007-02-10
p0_2 | p | 0 | 0 | r | | 2008-01-01
p1 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | i | | 2008-09-06
sys_p6 | p | 0 | 0 | i | | 2008-11-06
sys_p7 | p | 0 | 0 | i | | 2008-12-06
sys_p8 | p | 0 | 0 | i | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(16 rows)
alter table interval_sales merge partitions p0_1, p0_2, p1 into partition p01;
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | i | | 2008-09-06
sys_p6 | p | 0 | 0 | i | | 2008-11-06
sys_p7 | p | 0 | 0 | i | | 2008-12-06
sys_p8 | p | 0 | 0 | i | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(14 rows)
select *
from interval_sales partition (p0_1);
ERROR: partition "p0_1" of relation "interval_sales" does not exist
select *
from interval_sales partition (p0_2);
ERROR: partition "p0_2" of relation "interval_sales" does not exist
select *
from interval_sales partition (p1);
ERROR: partition "p1" of relation "interval_sales" does not exist
select *
from interval_sales partition (p01);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Fri Feb 09 00:00:00 2007 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 11 00:00:00 2007 | a | 1 | 1 | 1.00
1 | 1 | Mon Feb 11 00:00:00 2008 | a | 1 | 1 | 1.00
(3 rows)
-- 2.2.0 merge interval partitions in wrong order
select *
from interval_sales partition (sys_p6);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Nov 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (sys_p5);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Sep 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales merge partitions sys_p6, sys_p5 into partition sys_p6_p5;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.2.1 merge interval partitions in right order, but they are not continuous
alter table interval_sales merge partitions sys_p5, sys_p6 into partition sys_p5_p6;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.2.2 merge interval partitions in right order, and they are continuous.
select *
from interval_sales partition (sys_p6);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Nov 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (sys_p7);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Dec 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (sys_p8);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Jan 04 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | i | | 2008-09-06
sys_p6 | p | 0 | 0 | i | | 2008-11-06
sys_p7 | p | 0 | 0 | i | | 2008-12-06
sys_p8 | p | 0 | 0 | i | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(14 rows)
alter table interval_sales merge partitions sys_p6, sys_p7, sys_p8 into partition sys_p6_p7_p8;
select *
from interval_sales partition (sys_p6);
ERROR: partition "sys_p6" of relation "interval_sales" does not exist
select *
from interval_sales partition (sys_p7);
ERROR: partition "sys_p7" of relation "interval_sales" does not exist
select *
from interval_sales partition (sys_p8);
ERROR: partition "sys_p8" of relation "interval_sales" does not exist
select *
from interval_sales partition (sys_p6_p7_p8);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Nov 04 00:00:00 2008 | a | 1 | 1 | 1.00
1 | 1 | Thu Dec 04 00:00:00 2008 | a | 1 | 1 | 1.00
1 | 1 | Sun Jan 04 00:00:00 2009 | a | 1 | 1 | 1.00
(3 rows)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | r | | 2008-09-06
sys_p6_p7_p8 | p | 0 | 0 | r | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(12 rows)
-- 2.3 merge interval partition and range partition
-- FIRST, build a range partition which is continuous with a interval partition
alter table interval_sales merge partitions sys_p2, sys_p1 into partition sys_p2_p1;
-- 2.3.1 merge sys_p2_p1 with sys_p3 in wrong order
alter table interval_sales merge partitions sys_p3, sys_p2_p1 into partition sys_p2_p1_p3;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.3.2 merge sys_p2_p1 with sys_p3 in right order
select *
from interval_sales partition (sys_p2_p1);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
(3 rows)
select *
from interval_sales partition (sys_p3);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales merge partitions sys_p2_p1, sys_p3 into partition sys_p2_p1_p3;
select *
from interval_sales partition (sys_p2_p1_p3);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
(4 rows)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | r | | 2008-09-06
sys_p6_p7_p8 | p | 0 | 0 | r | | 2009-01-06
sys_p2_p1_p3 | p | 0 | 0 | r | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(10 rows)
-- 2.4.0 merge interval partition and range partition into one in wrong order
alter table interval_sales merge partitions sys_p9, sys_p2_p1_p3 into partition sys_p9_p2_p1_p3;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.4.1 merge interval partition and range partition into one in right order
alter table interval_sales merge partitions sys_p2_p1_p3, sys_p9 into partition sys_p9_p2_p1_p3;
select *
from interval_sales partition (sys_p9_p2_p1_p3);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Mon May 04 00:00:00 2009 | a | 1 | 1 | 1.00
(5 rows)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
-----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | r | | 2008-09-06
sys_p6_p7_p8 | p | 0 | 0 | r | | 2009-01-06
sys_p9_p2_p1_p3 | p | 0 | 0 | r | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(9 rows)
-- 2.5 merge interval partitions, which is divided by several interval partitions, which would fail
alter table interval_sales merge partitions sys_p10, sys_p12 into partition sys_p10_p12;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 3 drop indexes and table
drop table interval_sales;
-- B. test with index
CREATE TABLE interval_sales
(
prod_id NUMBER(6),
cust_id NUMBER,
time_id DATE,
channel_id CHAR(1),
promo_id NUMBER(6),
quantity_sold NUMBER(3),
amount_sold NUMBER(10, 2)
)
PARTITION BY RANGE (time_id)
INTERVAL
('1 MONTH')
(PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
create index interval_sales_time_id_idx on interval_sales (time_id) local;
create index interval_sales_quantity_sold_idx on interval_sales (quantity_sold) local;
alter table interval_sales split partition p0 at (to_date('2007-02-10', 'YYYY-MM-DD')) into (partition p0_1, partition p0_2);
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p0_1 | p | 0 | 0 | r | | 2007-02-10
p0_2 | p | 0 | 0 | r | | 2008-01-01
p1 | p | 0 | 0 | r | | 2008-05-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(4 rows)
insert into interval_sales
values (1, 1, to_date('9-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('20-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('08-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-4-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-11-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-12-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-01-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-5-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-6-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-7-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
-- 2 cases
-- 2.1.0 merge normal range partitions in bad order
select *
from interval_sales partition (p0_1);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Fri Feb 09 00:00:00 2007 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (p0_2);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Feb 11 00:00:00 2007 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (p1);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Mon Feb 11 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales merge partitions p1, p0_1, p0_2 into partition p01;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.1.1 merge normal range partitions in right order
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p0_1 | p | 0 | 0 | r | | 2007-02-10
p0_2 | p | 0 | 0 | r | | 2008-01-01
p1 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | i | | 2008-09-06
sys_p6 | p | 0 | 0 | i | | 2008-11-06
sys_p7 | p | 0 | 0 | i | | 2008-12-06
sys_p8 | p | 0 | 0 | i | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(16 rows)
alter table interval_sales merge partitions p0_1, p0_2, p1 into partition p01;
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | i | | 2008-09-06
sys_p6 | p | 0 | 0 | i | | 2008-11-06
sys_p7 | p | 0 | 0 | i | | 2008-12-06
sys_p8 | p | 0 | 0 | i | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(14 rows)
select *
from interval_sales partition (p0_1);
ERROR: partition "p0_1" of relation "interval_sales" does not exist
select *
from interval_sales partition (p0_2);
ERROR: partition "p0_2" of relation "interval_sales" does not exist
select *
from interval_sales partition (p1);
ERROR: partition "p1" of relation "interval_sales" does not exist
select *
from interval_sales partition (p01);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Fri Feb 09 00:00:00 2007 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 11 00:00:00 2007 | a | 1 | 1 | 1.00
1 | 1 | Mon Feb 11 00:00:00 2008 | a | 1 | 1 | 1.00
(3 rows)
-- 2.2.0 merge interval partitions in wrong order
select *
from interval_sales partition (sys_p6);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Nov 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (sys_p5);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Sep 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales merge partitions sys_p6, sys_p5 into partition sys_p6_p5;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.2.1 merge interval partitions in right order, but they are not continuous
alter table interval_sales merge partitions sys_p5, sys_p6 into partition sys_p5_p6;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.2.2 merge interval partitions in right order, and they are continuous.
select *
from interval_sales partition (sys_p6);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Nov 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (sys_p7);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Dec 04 00:00:00 2008 | a | 1 | 1 | 1.00
(1 row)
select *
from interval_sales partition (sys_p8);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Jan 04 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | i | | 2008-09-06
sys_p6 | p | 0 | 0 | i | | 2008-11-06
sys_p7 | p | 0 | 0 | i | | 2008-12-06
sys_p8 | p | 0 | 0 | i | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(14 rows)
alter table interval_sales merge partitions sys_p6, sys_p7, sys_p8 into partition sys_p6_p7_p8;
select *
from interval_sales partition (sys_p6);
ERROR: partition "sys_p6" of relation "interval_sales" does not exist
select *
from interval_sales partition (sys_p7);
ERROR: partition "sys_p7" of relation "interval_sales" does not exist
select *
from interval_sales partition (sys_p8);
ERROR: partition "sys_p8" of relation "interval_sales" does not exist
select *
from interval_sales partition (sys_p6_p7_p8);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Nov 04 00:00:00 2008 | a | 1 | 1 | 1.00
1 | 1 | Thu Dec 04 00:00:00 2008 | a | 1 | 1 | 1.00
1 | 1 | Sun Jan 04 00:00:00 2009 | a | 1 | 1 | 1.00
(3 rows)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | r | | 2008-09-06
sys_p6_p7_p8 | p | 0 | 0 | r | | 2009-01-06
sys_p2 | p | 0 | 0 | i | | 2009-02-06
sys_p1 | p | 0 | 0 | i | | 2009-03-06
sys_p3 | p | 0 | 0 | i | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(12 rows)
-- 2.3 merge interval partition and range partition
-- FIRST, build a range partition which is continuous with a interval partition
alter table interval_sales merge partitions sys_p2, sys_p1 into partition sys_p2_p1;
-- 2.3.1 merge sys_p2_p1 with sys_p3 in wrong order
alter table interval_sales merge partitions sys_p3, sys_p2_p1 into partition sys_p2_p1_p3;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.3.2 merge sys_p2_p1 with sys_p3 in right order
select *
from interval_sales partition (sys_p2_p1);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
(3 rows)
select *
from interval_sales partition (sys_p3);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales merge partitions sys_p2_p1, sys_p3 into partition sys_p2_p1_p3;
select *
from interval_sales partition (sys_p2_p1_p3);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
(4 rows)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | r | | 2008-09-06
sys_p6_p7_p8 | p | 0 | 0 | r | | 2009-01-06
sys_p2_p1_p3 | p | 0 | 0 | r | | 2009-04-06
sys_p9 | p | 0 | 0 | i | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(10 rows)
-- 2.4.0 merge interval partition and range partition into one in wrong order
alter table interval_sales merge partitions sys_p9, sys_p2_p1_p3 into partition sys_p9_p2_p1_p3;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.4.1 merge interval partition and range partition into one in right order
alter table interval_sales merge partitions sys_p2_p1_p3, sys_p9 into partition sys_p9_p2_p1_p3;
select *
from interval_sales partition (sys_p9_p2_p1_p3);
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Mon May 04 00:00:00 2009 | a | 1 | 1 | 1.00
(5 rows)
execute pg_partition_sql('interval_sales');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
-----------------+----------+----------+-------------+--------------+-------------+------------
p01 | p | 0 | 0 | r | | 2008-05-06
sys_p5 | p | 0 | 0 | r | | 2008-09-06
sys_p6_p7_p8 | p | 0 | 0 | r | | 2009-01-06
sys_p9_p2_p1_p3 | p | 0 | 0 | r | | 2009-05-06
sys_p10 | p | 0 | 0 | i | | 2009-06-06
sys_p11 | p | 0 | 0 | i | | 2009-07-06
sys_p4 | p | 0 | 0 | i | | 2009-08-06
sys_p12 | p | 0 | 0 | i | | 2009-09-06
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
(9 rows)
-- 2.5 merge interval partitions, which is divided by several interval partitions, will failed
alter table interval_sales merge partitions sys_p10, sys_p12 into partition sys_p10_p12;
ERROR: source partitions must be continuous and in ascending order of boundary
-- 2.6 case that failed to update new partition's type
drop table if exists partiton_table_001;
NOTICE: table "partiton_table_001" does not exist, skipping
create table partiton_table_001(
COL_4 date
)
PARTITION BY RANGE (COL_4)
INTERVAL ('1 month')
(
PARTITION partiton_table_001_p1 VALUES LESS THAN (date'2020-03-01'),
PARTITION partiton_table_001_p2 VALUES LESS THAN (date'2020-04-01'),
PARTITION partiton_table_001_p3 VALUES LESS THAN (date'2020-05-01')
);
-- @插入的分区键值
insert into partiton_table_001 values (date'2020-02-23');
insert into partiton_table_001 values (date'2020-03-23');
insert into partiton_table_001 values (date'2020-04-23');
insert into partiton_table_001 values (date'2020-05-23');
insert into partiton_table_001 values (date'2020-06-23');
insert into partiton_table_001 values (date'2020-07-23');
-- @查看分区表、分区表索引信息
execute pg_partition_sql('partiton_table_001');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
-----------------------+----------+----------+-------------+--------------+-------------+------------
partiton_table_001_p1 | p | 0 | 0 | r | | 2020-03-01
partiton_table_001_p2 | p | 0 | 0 | r | | 2020-04-01
partiton_table_001_p3 | p | 0 | 0 | r | | 2020-05-01
sys_p1 | p | 0 | 0 | i | | 2020-06-01
sys_p2 | p | 0 | 0 | i | | 2020-07-01
sys_p3 | p | 0 | 0 | i | | 2020-08-01
partiton_table_001 | r | 0 | 0 | i | {"1 month"} |
(7 rows)
alter table partiton_table_001 merge partitions sys_p1, sys_p2 into PARTITION sys_p4;
execute pg_partition_sql('partiton_table_001');
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundary
-----------------------+----------+----------+-------------+--------------+-------------+------------
partiton_table_001_p1 | p | 0 | 0 | r | | 2020-03-01
partiton_table_001_p2 | p | 0 | 0 | r | | 2020-04-01
partiton_table_001_p3 | p | 0 | 0 | r | | 2020-05-01
sys_p4 | p | 0 | 0 | r | | 2020-07-01
sys_p3 | p | 0 | 0 | i | | 2020-08-01
partiton_table_001 | r | 0 | 0 | i | {"1 month"} |
(6 rows)
drop table if exists partiton_table_001;
-- 3 drop indexes and table
drop index interval_sales_time_id_idx;
drop index interval_sales_quantity_sold_idx;
drop table interval_sales;

View File

@ -0,0 +1,381 @@
-- 1 init environment
CREATE TABLE interval_sales
( prod_id NUMBER(6)
, cust_id NUMBER
, time_id DATE
, channel_id CHAR(1)
, promo_id NUMBER(6)
, quantity_sold NUMBER(3)
, amount_sold NUMBER(10,2)
)
PARTITION BY RANGE (time_id)
INTERVAL('1 MONTH')
( PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
alter table interval_sales split partition p0 at (to_date('2007-02-10', 'YYYY-MM-DD')) into (partition p0_1, partition p0_2);
select * from interval_sales order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
(4 rows)
insert into interval_sales values(1, 1, to_date('20-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('05-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('08-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('05-4-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('05-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-9-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-11-2018', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-01-2019', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-02-2019', 'DD-MM-YYYY'), 'a', 1, 1, 1);
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1 | p | 0 | 0 | i | | {"Fri Mar 06 00:00:00 2009"}
sys_p2 | p | 0 | 0 | i | | {"Fri Feb 06 00:00:00 2009"}
sys_p3 | p | 0 | 0 | i | | {"Mon Apr 06 00:00:00 2009"}
sys_p4 | p | 0 | 0 | i | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | i | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(12 rows)
-- 2. cases
-- 2.1 split a interval partition, should be successful. and sys_p2 should be changed to range partition
select * from interval_sales partition(sys_p1) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
alter table interval_sales split partition sys_p1 at (to_date('2009-02-10', 'YYYY-MM-DD')) into (partition sys_p1_1, partition sys_p1_2);
select * from interval_sales partition(sys_p1_1) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Feb 08 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
select * from interval_sales partition(sys_p1_2) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Fri Feb 20 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1_1 | p | 0 | 0 | r | | {"Tue Feb 10 00:00:00 2009"}
sys_p1_2 | p | 0 | 0 | r | | {"Fri Mar 06 00:00:00 2009"}
sys_p2 | p | 0 | 0 | r | | {"Fri Feb 06 00:00:00 2009"}
sys_p3 | p | 0 | 0 | i | | {"Mon Apr 06 00:00:00 2009"}
sys_p4 | p | 0 | 0 | i | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | r | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(13 rows)
-- 2.2 split a range partition. (this partition has been changed to range partition in previous step)
select * from interval_sales partition(sys_p2) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales split partition sys_p2 at (to_date('2009-01-10', 'YYYY-MM-DD')) into (partition sys_p2_1, partition sys_p2_2);
select * from interval_sales partition(sys_p2_1) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(sys_p2_2) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Thu Feb 05 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1_1 | p | 0 | 0 | r | | {"Tue Feb 10 00:00:00 2009"}
sys_p1_2 | p | 0 | 0 | r | | {"Fri Mar 06 00:00:00 2009"}
sys_p2_1 | p | 0 | 0 | r | | {"Sat Jan 10 00:00:00 2009"}
sys_p2_2 | p | 0 | 0 | r | | {"Fri Feb 06 00:00:00 2009"}
sys_p3 | p | 0 | 0 | i | | {"Mon Apr 06 00:00:00 2009"}
sys_p4 | p | 0 | 0 | i | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | r | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(14 rows)
-- 2.3 split interval partition sys_p3, successful, and no other partitions should be changed.
select * from interval_sales partition(sys_p3) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
alter table interval_sales split partition sys_p3 at (to_date('2009-04-5', 'YYYY-MM-DD')) into (partition sys_p3_1, partition sys_p3_2);
select * from interval_sales partition(sys_p3_1) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(sys_p3_2) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Apr 05 00:00:00 2009 | a | 1 | 1 | 1.00
(1 row)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1_1 | p | 0 | 0 | r | | {"Tue Feb 10 00:00:00 2009"}
sys_p1_2 | p | 0 | 0 | r | | {"Fri Mar 06 00:00:00 2009"}
sys_p2_1 | p | 0 | 0 | r | | {"Sat Jan 10 00:00:00 2009"}
sys_p2_2 | p | 0 | 0 | r | | {"Fri Feb 06 00:00:00 2009"}
sys_p3_1 | p | 0 | 0 | r | | {"Sun Apr 05 00:00:00 2009"}
sys_p3_2 | p | 0 | 0 | r | | {"Mon Apr 06 00:00:00 2009"}
sys_p4 | p | 0 | 0 | i | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | r | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(15 rows)
-- 2.4 split interval partition sys_p4 at its lower bound, should fail.
select * from interval_sales partition(sys_p4) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Aug 04 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Wed Aug 05 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
alter table interval_sales split partition sys_p4 at (to_date('2009-07-6', 'YYYY-MM-DD')) into (partition sys_p4_1, partition sys_p4_2);
ERROR: split point is too low
select * from interval_sales partition(sys_p4) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Aug 04 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Wed Aug 05 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1_1 | p | 0 | 0 | r | | {"Tue Feb 10 00:00:00 2009"}
sys_p1_2 | p | 0 | 0 | r | | {"Fri Mar 06 00:00:00 2009"}
sys_p2_1 | p | 0 | 0 | r | | {"Sat Jan 10 00:00:00 2009"}
sys_p2_2 | p | 0 | 0 | r | | {"Fri Feb 06 00:00:00 2009"}
sys_p3_1 | p | 0 | 0 | r | | {"Sun Apr 05 00:00:00 2009"}
sys_p3_2 | p | 0 | 0 | r | | {"Mon Apr 06 00:00:00 2009"}
sys_p4 | p | 0 | 0 | i | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | r | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(15 rows)
-- 2.5 split interval partition sys_p4 at its upper bound, should fail.
select * from interval_sales partition(sys_p4) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Aug 04 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Wed Aug 05 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
alter table interval_sales split partition sys_p4 at (to_date('2009-08-06', 'YYYY-MM-DD')) into (partition sys_p4_1, partition sys_p4_2);
ERROR: split point is too high
select * from interval_sales partition(sys_p4) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Aug 04 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Wed Aug 05 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1_1 | p | 0 | 0 | r | | {"Tue Feb 10 00:00:00 2009"}
sys_p1_2 | p | 0 | 0 | r | | {"Fri Mar 06 00:00:00 2009"}
sys_p2_1 | p | 0 | 0 | r | | {"Sat Jan 10 00:00:00 2009"}
sys_p2_2 | p | 0 | 0 | r | | {"Fri Feb 06 00:00:00 2009"}
sys_p3_1 | p | 0 | 0 | r | | {"Sun Apr 05 00:00:00 2009"}
sys_p3_2 | p | 0 | 0 | r | | {"Mon Apr 06 00:00:00 2009"}
sys_p4 | p | 0 | 0 | i | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | r | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(15 rows)
-- 2.6 split sys_P4 at a valid point, should be successful, and no other partitions changed.
select * from interval_sales partition(sys_p4) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Aug 04 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Wed Aug 05 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
alter table interval_sales split partition sys_p4 at (to_date('2009-07-10', 'YYYY-MM-DD')) into (partition sys_p4_1, partition sys_p4_2);
select * from interval_sales partition(sys_p4_1) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(sys_p4_2) order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Tue Aug 04 00:00:00 2009 | a | 1 | 1 | 1.00
1 | 1 | Wed Aug 05 00:00:00 2009 | a | 1 | 1 | 1.00
(2 rows)
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
relname | parttype | rangenum | intervalnum | partstrategy | interval | boundaries
----------------+----------+----------+-------------+--------------+-------------+------------------------------
interval_sales | r | 0 | 0 | i | {"1 MONTH"} |
p0_1 | p | 0 | 0 | r | | {"Sat Feb 10 00:00:00 2007"}
p0_2 | p | 0 | 0 | r | | {"Tue Jan 01 00:00:00 2008"}
p1 | p | 0 | 0 | r | | {"Tue May 06 00:00:00 2008"}
sys_p1_1 | p | 0 | 0 | r | | {"Tue Feb 10 00:00:00 2009"}
sys_p1_2 | p | 0 | 0 | r | | {"Fri Mar 06 00:00:00 2009"}
sys_p2_1 | p | 0 | 0 | r | | {"Sat Jan 10 00:00:00 2009"}
sys_p2_2 | p | 0 | 0 | r | | {"Fri Feb 06 00:00:00 2009"}
sys_p3_1 | p | 0 | 0 | r | | {"Sun Apr 05 00:00:00 2009"}
sys_p3_2 | p | 0 | 0 | r | | {"Mon Apr 06 00:00:00 2009"}
sys_p4_1 | p | 0 | 0 | r | | {"Fri Jul 10 00:00:00 2009"}
sys_p4_2 | p | 0 | 0 | r | | {"Thu Aug 06 00:00:00 2009"}
sys_p5 | p | 0 | 0 | r | | {"Sat Sep 06 00:00:00 2008"}
sys_p6 | p | 0 | 0 | i | | {"Tue Nov 06 00:00:00 2018"}
sys_p7 | p | 0 | 0 | i | | {"Sun Jan 06 00:00:00 2019"}
sys_p8 | p | 0 | 0 | i | | {"Wed Feb 06 00:00:00 2019"}
(16 rows)
-- 2.7.0 split p1 using partition def list, no split point given, first partition invalid, equal to previous partition p0_2's boundaries.
alter table interval_sales split partition p1 into
(partition p1_1 values less than (to_date('2008-01-01', 'YYYY-MM-DD')),
partition p1_2 values less than (to_date('2008-03-06', 'YYYY-MM-DD')),
partition p1_3 values less than (to_date('2008-04-06', 'YYYY-MM-DD')),
partition p1_4 values less than (to_date('2008-05-06', 'YYYY-MM-DD')));
ERROR: the bound of the first resulting partition is too low
-- 2.7.1 split p1 using partition def list, no split point given, first partition invalid, less than previous partition p0_2's boundaries.
alter table interval_sales split partition p1 into
(partition p1_1 values less than (to_date('2007-01-01', 'YYYY-MM-DD')),
partition p1_2 values less than (to_date('2008-03-06', 'YYYY-MM-DD')),
partition p1_3 values less than (to_date('2008-04-06', 'YYYY-MM-DD')),
partition p1_4 values less than (to_date('2008-05-06', 'YYYY-MM-DD')));
ERROR: the bound of the first resulting partition is too low
-- 2.7.2 split p1 using partition def list, no split point given, first partition valid, greater than previous partition p0_2's boundaries.
alter table interval_sales split partition p1 into
(partition p1_1 values less than (to_date('2008-01-03', 'YYYY-MM-DD')),
partition p1_2 values less than (to_date('2008-03-06', 'YYYY-MM-DD')),
partition p1_3 values less than (to_date('2008-04-06', 'YYYY-MM-DD')),
partition p1_4 values less than (to_date('2008-05-06', 'YYYY-MM-DD')));
select * from interval_sales partition(p1_1)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(p1_2)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(p1_3)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(p1_4)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
-- 2.8.1 split sys_p6 using partition def list, no split point given, first partition invalid, equal to self's lower boundaries.
alter table interval_sales split partition sys_p6 into
(partition sys_p6_1 values less than (to_date('2018-10-6', 'YYYY-MM-DD')),
partition sys_p6_2 values less than (to_date('2018-10-29', 'YYYY-MM-DD')),
partition sys_p6_3 values less than (to_date('2018-11-01', 'YYYY-MM-DD')),
partition sys_p6_4 values less than (to_date('2018-11-06', 'YYYY-MM-DD')));
ERROR: the bound of the first resulting partition is too low
-- 2.8.2 split sys_p6 using partition def list, no split point given, first partition invalid, less than self's lower boundaries.
alter table interval_sales split partition sys_p6 into
(partition sys_p6_1 values less than (to_date('2018-10-5', 'YYYY-MM-DD')),
partition sys_p6_2 values less than (to_date('2018-10-29', 'YYYY-MM-DD')),
partition sys_p6_3 values less than (to_date('2018-11-01', 'YYYY-MM-DD')),
partition sys_p6_4 values less than (to_date('2018-11-06', 'YYYY-MM-DD')));
ERROR: the bound of the first resulting partition is too low
-- 2.8.3 split sys_p6 using partition def list, no split point given, first partition valid, greater than self's lower boundaries.
alter table interval_sales split partition sys_p6 into
(partition sys_p6_1 values less than (to_date('2018-10-8', 'YYYY-MM-DD')),
partition sys_p6_2 values less than (to_date('2018-10-29', 'YYYY-MM-DD')),
partition sys_p6_3 values less than (to_date('2018-11-01', 'YYYY-MM-DD')),
partition sys_p6_4 values less than (to_date('2018-11-06', 'YYYY-MM-DD')));
select * from interval_sales partition(sys_p6_1)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(sys_p6_2)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(sys_p6_3)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+---------+------------+----------+---------------+-------------
(0 rows)
select * from interval_sales partition(sys_p6_4)order by time_id;
prod_id | cust_id | time_id | channel_id | promo_id | quantity_sold | amount_sold
---------+---------+--------------------------+------------+----------+---------------+-------------
1 | 1 | Sun Nov 04 00:00:00 2018 | a | 1 | 1 | 1.00
(1 row)
-- 3 drop table interval_sales
drop table interval_sales;

View File

@ -334,7 +334,8 @@ select class.relname, ind.indisclustered
ALTER INDEX idx1_partition_unsable_index_1 MODIFY PARTITION idx1_partition_unsable_index_1_p1 UNUSABLE;
ALTER TABLE partition_unsable_index_1 MERGE PARTITIONS partition_unsable_index_1_p0, p2_partition_unsable_index_3
INTO PARTITION px_partition_unsable_index_3;
ERROR: can not merge partition against interval partitioned table
ERROR: can't merge partition bacause partition partition_unsable_index_1_p0 has unusable local index
HINT: please reindex the unusable index first.
--rebuild unusable index partition
ALTER INDEX idx1_partition_unsable_index_1 REBUILD PARTITION idx1_partition_unsable_index_1_p1;
--5.3 exchange

View File

@ -138,14 +138,10 @@ select * from interval_normal_date order by logdate;
-- split partition
ALTER TABLE interval_normal_date SPLIT PARTITION sys_p1 AT ('2020-04-01 00:00:00') INTO
(
PARTITION sys_p6,
PARTITION sys_p7
PARTITION sys_p1_1,
PARTITION sys_p1_2
);
-- mgerge partition
ALTER TABLE interval_normal_date MERGE PARTITIONS interval_normal_date_p1, sys_p1 into PARTITION sys_p8;
ALTER TABLE interval_normal_date MERGE PARTITIONS sys_p1, sys_p4 into PARTITION sys_p9;
--
---- add partition is not supported;
--
@ -172,7 +168,7 @@ select relname, parttype, partstrategy, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_normal_date')
order by relname;
ALTER TABLE interval_normal_date RENAME PARTITION sys_p2 To sys_p32780;
ALTER TABLE interval_normal_date RENAME PARTITION sys_p1 To sys_p32780;
insert into interval_normal_date values ('2040-06-24');
select relname, parttype, partstrategy, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_normal_date')
@ -241,4 +237,4 @@ drop tablespace hw_partition_interval_tsp5;
drop tablespace hw_partition_interval_tsp6;
\! rm -fr '@testtablespace@/hw_partition_interval_tsp4'
\! rm -fr '@testtablespace@/hw_partition_interval_tsp5'
\! rm -fr '@testtablespace@/hw_partition_interval_tsp6'
\! rm -fr '@testtablespace@/hw_partition_interval_tsp6'

View File

@ -298,15 +298,9 @@ select * from interval_normal_date order by logdate;
-- split partition
ALTER TABLE interval_normal_date SPLIT PARTITION sys_p1 AT ('2020-04-01 00:00:00') INTO
(
PARTITION sys_p6,
PARTITION sys_p7
PARTITION sys_p1_1,
PARTITION sys_p1_2
);
ERROR: can not split partition against interval partitioned table
-- mgerge partition
ALTER TABLE interval_normal_date MERGE PARTITIONS interval_normal_date_p1, sys_p1 into PARTITION sys_p8;
ERROR: can not merge partition against interval partitioned table
ALTER TABLE interval_normal_date MERGE PARTITIONS sys_p1, sys_p4 into PARTITION sys_p9;
ERROR: can not merge partition against interval partitioned table
--
---- add partition is not supported;
--
@ -326,10 +320,11 @@ select relname, parttype, partstrategy, boundaries from pg_partition
interval_normal_date_p1 | p | r | {2020-03-01}
my_sys_p4 | p | i | {"Wed Jun 03 00:00:00 2020"}
my_sys_p5 | p | i | {"Sat Mar 02 00:00:00 2030"}
sys_p1 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p1_1 | p | r | {"Wed Apr 01 00:00:00 2020"}
sys_p1_2 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p3 | p | i | {"Thu Jun 04 00:00:00 2020"}
sys_p6 | p | i | {"Thu Jun 21 00:00:00 2040"}
(7 rows)
(8 rows)
ALTER TABLE interval_normal_date RENAME PARTITION sys_p6 To my_sys_p6;
insert into interval_normal_date values ('2040-06-21');
@ -343,10 +338,11 @@ select relname, parttype, partstrategy, boundaries from pg_partition
my_sys_p4 | p | i | {"Wed Jun 03 00:00:00 2020"}
my_sys_p5 | p | i | {"Sat Mar 02 00:00:00 2030"}
my_sys_p6 | p | i | {"Thu Jun 21 00:00:00 2040"}
sys_p1 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p1_1 | p | r | {"Wed Apr 01 00:00:00 2020"}
sys_p1_2 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p3 | p | i | {"Thu Jun 04 00:00:00 2020"}
sys_p4 | p | i | {"Fri Jun 22 00:00:00 2040"}
(8 rows)
(9 rows)
ALTER TABLE interval_normal_date RENAME PARTITION sys_p4 To sys_p32767;
insert into interval_normal_date values ('2040-06-22');
@ -360,13 +356,14 @@ select relname, parttype, partstrategy, boundaries from pg_partition
my_sys_p4 | p | i | {"Wed Jun 03 00:00:00 2020"}
my_sys_p5 | p | i | {"Sat Mar 02 00:00:00 2030"}
my_sys_p6 | p | i | {"Thu Jun 21 00:00:00 2040"}
sys_p1 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p2 | p | i | {"Sat Jun 23 00:00:00 2040"}
sys_p1 | p | i | {"Sat Jun 23 00:00:00 2040"}
sys_p1_1 | p | r | {"Wed Apr 01 00:00:00 2020"}
sys_p1_2 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p3 | p | i | {"Thu Jun 04 00:00:00 2020"}
sys_p32767 | p | i | {"Fri Jun 22 00:00:00 2040"}
(9 rows)
(10 rows)
ALTER TABLE interval_normal_date RENAME PARTITION sys_p2 To sys_p32780;
ALTER TABLE interval_normal_date RENAME PARTITION sys_p1 To sys_p32780;
insert into interval_normal_date values ('2040-06-24');
select relname, parttype, partstrategy, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_normal_date')
@ -378,12 +375,13 @@ select relname, parttype, partstrategy, boundaries from pg_partition
my_sys_p4 | p | i | {"Wed Jun 03 00:00:00 2020"}
my_sys_p5 | p | i | {"Sat Mar 02 00:00:00 2030"}
my_sys_p6 | p | i | {"Thu Jun 21 00:00:00 2040"}
sys_p1 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p14 | p | i | {"Mon Jun 25 00:00:00 2040"}
sys_p1_1 | p | r | {"Wed Apr 01 00:00:00 2020"}
sys_p1_2 | p | r | {"Tue Jun 02 00:00:00 2020"}
sys_p3 | p | i | {"Thu Jun 04 00:00:00 2020"}
sys_p32767 | p | i | {"Fri Jun 22 00:00:00 2040"}
sys_p32780 | p | i | {"Sat Jun 23 00:00:00 2040"}
(10 rows)
(11 rows)
--clean up
drop table interval_normal_date;

View File

@ -24,3 +24,5 @@ test: hw_partition_interval_check_syntax
# Below two teste are unstable, temporarily ignoring. This is same to distribute_dattistic, relallvisible, Dongwang will solve the problem.
#test: hw_partition_vacuum_full
#test: hw_partition_vacuum
test: hw_partition_interval_split
test: hw_partition_interval_merge

View File

@ -323,11 +323,11 @@ INTERVAL('1 MONTH')
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
select relname, parentid, reltoastrelid, boundaries from pg_partition;
select relname, case when reltoastrelid > 0 then 'TRUE' else 'FALSE' end as has_toastrelid, boundaries from pg_partition;
insert into interval_sales values (generate_series(1,10), generate_series(1,10), generate_series(TO_DATE('2020-01-01', 'YYYY-MM-DD'),TO_DATE('2020-07-01', 'YYYY-MM-DD'),'1 day'), 1, 1, 1, 1);
select relname, parentid, reltoastrelid, boundaries from pg_partition;
select relname, case when reltoastrelid > 0 then 'TRUE' else 'FALSE' end as has_toastrelid, boundaries from pg_partition;
drop table interval_sales;

View File

@ -0,0 +1,318 @@
-- 1 init environment
set DateStyle = 'Postgres';
prepare pg_partition_sql(char) as
select relname,
parttype,
rangenum,
intervalnum,
partstrategy,
interval,
to_char(to_date(boundaries[1], 'Dy Mon DD hh24:mi:ss YYYY'), 'YYYY-MM-DD') boundary
from pg_partition
where parentid = (select oid from pg_class where relname = $1)
order by to_date(boundaries[1], 'Dy Mon DD hh24:mi:ss YYYY');
-- A. Test without index
CREATE TABLE interval_sales
(
prod_id NUMBER(6),
cust_id NUMBER,
time_id DATE,
channel_id CHAR(1),
promo_id NUMBER(6),
quantity_sold NUMBER(3),
amount_sold NUMBER(10, 2)
)
PARTITION BY RANGE (time_id)
INTERVAL
('1 MONTH')
(PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
alter table interval_sales split partition p0 at (to_date('2007-02-10', 'YYYY-MM-DD')) into (partition p0_1, partition p0_2);
execute pg_partition_sql('interval_sales');
insert into interval_sales
values (1, 1, to_date('9-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('20-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('08-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-4-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-11-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-12-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-01-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-5-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-6-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-7-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
-- 2 cases
-- 2.1.0 merge normal range partitions in bad order
select *
from interval_sales partition (p0_1);
select *
from interval_sales partition (p0_2);
select *
from interval_sales partition (p1);
alter table interval_sales merge partitions p1, p0_1, p0_2 into partition p01;
-- 2.1.1 merge normal range partitions in right order
execute pg_partition_sql('interval_sales');
alter table interval_sales merge partitions p0_1, p0_2, p1 into partition p01;
execute pg_partition_sql('interval_sales');
select *
from interval_sales partition (p0_1);
select *
from interval_sales partition (p0_2);
select *
from interval_sales partition (p1);
select *
from interval_sales partition (p01);
-- 2.2.0 merge interval partitions in wrong order
select *
from interval_sales partition (sys_p6);
select *
from interval_sales partition (sys_p5);
alter table interval_sales merge partitions sys_p6, sys_p5 into partition sys_p6_p5;
-- 2.2.1 merge interval partitions in right order, but they are not continuous
alter table interval_sales merge partitions sys_p5, sys_p6 into partition sys_p5_p6;
-- 2.2.2 merge interval partitions in right order, and they are continuous.
select *
from interval_sales partition (sys_p6);
select *
from interval_sales partition (sys_p7);
select *
from interval_sales partition (sys_p8);
execute pg_partition_sql('interval_sales');
alter table interval_sales merge partitions sys_p6, sys_p7, sys_p8 into partition sys_p6_p7_p8;
select *
from interval_sales partition (sys_p6);
select *
from interval_sales partition (sys_p7);
select *
from interval_sales partition (sys_p8);
select *
from interval_sales partition (sys_p6_p7_p8);
execute pg_partition_sql('interval_sales');
-- 2.3 merge interval partition and range partition
-- FIRST, build a range partition which is continuous with a interval partition
alter table interval_sales merge partitions sys_p2, sys_p1 into partition sys_p2_p1;
-- 2.3.1 merge sys_p2_p1 with sys_p3 in wrong order
alter table interval_sales merge partitions sys_p3, sys_p2_p1 into partition sys_p2_p1_p3;
-- 2.3.2 merge sys_p2_p1 with sys_p3 in right order
select *
from interval_sales partition (sys_p2_p1);
select *
from interval_sales partition (sys_p3);
alter table interval_sales merge partitions sys_p2_p1, sys_p3 into partition sys_p2_p1_p3;
select *
from interval_sales partition (sys_p2_p1_p3);
execute pg_partition_sql('interval_sales');
-- 2.4.0 merge interval partition and range partition into one in wrong order
alter table interval_sales merge partitions sys_p9, sys_p2_p1_p3 into partition sys_p9_p2_p1_p3;
-- 2.4.1 merge interval partition and range partition into one in right order
alter table interval_sales merge partitions sys_p2_p1_p3, sys_p9 into partition sys_p9_p2_p1_p3;
select *
from interval_sales partition (sys_p9_p2_p1_p3);
execute pg_partition_sql('interval_sales');
-- 2.5 merge interval partitions, which is divided by several interval partitions, which would fail
alter table interval_sales merge partitions sys_p10, sys_p12 into partition sys_p10_p12;
-- 3 drop indexes and table
drop table interval_sales;
-- B. test with index
CREATE TABLE interval_sales
(
prod_id NUMBER(6),
cust_id NUMBER,
time_id DATE,
channel_id CHAR(1),
promo_id NUMBER(6),
quantity_sold NUMBER(3),
amount_sold NUMBER(10, 2)
)
PARTITION BY RANGE (time_id)
INTERVAL
('1 MONTH')
(PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
create index interval_sales_time_id_idx on interval_sales (time_id) local;
create index interval_sales_quantity_sold_idx on interval_sales (quantity_sold) local;
alter table interval_sales split partition p0 at (to_date('2007-02-10', 'YYYY-MM-DD')) into (partition p0_1, partition p0_2);
execute pg_partition_sql('interval_sales');
insert into interval_sales
values (1, 1, to_date('9-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2007', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('11-2-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('20-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('08-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-4-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('05-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-11-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-12-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-01-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-5-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-6-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-7-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales
values (1, 1, to_date('04-9-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
-- 2 cases
-- 2.1.0 merge normal range partitions in bad order
select *
from interval_sales partition (p0_1);
select *
from interval_sales partition (p0_2);
select *
from interval_sales partition (p1);
alter table interval_sales merge partitions p1, p0_1, p0_2 into partition p01;
-- 2.1.1 merge normal range partitions in right order
execute pg_partition_sql('interval_sales');
alter table interval_sales merge partitions p0_1, p0_2, p1 into partition p01;
execute pg_partition_sql('interval_sales');
select *
from interval_sales partition (p0_1);
select *
from interval_sales partition (p0_2);
select *
from interval_sales partition (p1);
select *
from interval_sales partition (p01);
-- 2.2.0 merge interval partitions in wrong order
select *
from interval_sales partition (sys_p6);
select *
from interval_sales partition (sys_p5);
alter table interval_sales merge partitions sys_p6, sys_p5 into partition sys_p6_p5;
-- 2.2.1 merge interval partitions in right order, but they are not continuous
alter table interval_sales merge partitions sys_p5, sys_p6 into partition sys_p5_p6;
-- 2.2.2 merge interval partitions in right order, and they are continuous.
select *
from interval_sales partition (sys_p6);
select *
from interval_sales partition (sys_p7);
select *
from interval_sales partition (sys_p8);
execute pg_partition_sql('interval_sales');
alter table interval_sales merge partitions sys_p6, sys_p7, sys_p8 into partition sys_p6_p7_p8;
select *
from interval_sales partition (sys_p6);
select *
from interval_sales partition (sys_p7);
select *
from interval_sales partition (sys_p8);
select *
from interval_sales partition (sys_p6_p7_p8);
execute pg_partition_sql('interval_sales');
-- 2.3 merge interval partition and range partition
-- FIRST, build a range partition which is continuous with a interval partition
alter table interval_sales merge partitions sys_p2, sys_p1 into partition sys_p2_p1;
-- 2.3.1 merge sys_p2_p1 with sys_p3 in wrong order
alter table interval_sales merge partitions sys_p3, sys_p2_p1 into partition sys_p2_p1_p3;
-- 2.3.2 merge sys_p2_p1 with sys_p3 in right order
select *
from interval_sales partition (sys_p2_p1);
select *
from interval_sales partition (sys_p3);
alter table interval_sales merge partitions sys_p2_p1, sys_p3 into partition sys_p2_p1_p3;
select *
from interval_sales partition (sys_p2_p1_p3);
execute pg_partition_sql('interval_sales');
-- 2.4.0 merge interval partition and range partition into one in wrong order
alter table interval_sales merge partitions sys_p9, sys_p2_p1_p3 into partition sys_p9_p2_p1_p3;
-- 2.4.1 merge interval partition and range partition into one in right order
alter table interval_sales merge partitions sys_p2_p1_p3, sys_p9 into partition sys_p9_p2_p1_p3;
select *
from interval_sales partition (sys_p9_p2_p1_p3);
execute pg_partition_sql('interval_sales');
-- 2.5 merge interval partitions, which is divided by several interval partitions, will failed
alter table interval_sales merge partitions sys_p10, sys_p12 into partition sys_p10_p12;
-- 2.6 case that failed to update new partition's type
drop table if exists partiton_table_001;
create table partiton_table_001(
COL_4 date
)
PARTITION BY RANGE (COL_4)
INTERVAL ('1 month')
(
PARTITION partiton_table_001_p1 VALUES LESS THAN (date'2020-03-01'),
PARTITION partiton_table_001_p2 VALUES LESS THAN (date'2020-04-01'),
PARTITION partiton_table_001_p3 VALUES LESS THAN (date'2020-05-01')
);
-- @插入的分区键值
insert into partiton_table_001 values (date'2020-02-23');
insert into partiton_table_001 values (date'2020-03-23');
insert into partiton_table_001 values (date'2020-04-23');
insert into partiton_table_001 values (date'2020-05-23');
insert into partiton_table_001 values (date'2020-06-23');
insert into partiton_table_001 values (date'2020-07-23');
-- @查看分区表、分区表索引信息
execute pg_partition_sql('partiton_table_001');
alter table partiton_table_001 merge partitions sys_p1, sys_p2 into PARTITION sys_p4;
execute pg_partition_sql('partiton_table_001');
drop table if exists partiton_table_001;
-- 3 drop indexes and table
drop index interval_sales_time_id_idx;
drop index interval_sales_quantity_sold_idx;
drop table interval_sales;

View File

@ -0,0 +1,130 @@
-- 1 init environment
CREATE TABLE interval_sales
( prod_id NUMBER(6)
, cust_id NUMBER
, time_id DATE
, channel_id CHAR(1)
, promo_id NUMBER(6)
, quantity_sold NUMBER(3)
, amount_sold NUMBER(10,2)
)
PARTITION BY RANGE (time_id)
INTERVAL('1 MONTH')
( PARTITION p0 VALUES LESS THAN (TO_DATE('1-1-2008', 'DD-MM-YYYY')),
PARTITION p1 VALUES LESS THAN (TO_DATE('6-5-2008', 'DD-MM-YYYY'))
);
alter table interval_sales split partition p0 at (to_date('2007-02-10', 'YYYY-MM-DD')) into (partition p0_1, partition p0_2);
select * from interval_sales order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
insert into interval_sales values(1, 1, to_date('20-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('05-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('08-2-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('05-4-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('05-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-8-2009', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-9-2008', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-11-2018', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-01-2019', 'DD-MM-YYYY'), 'a', 1, 1, 1);
insert into interval_sales values(1, 1, to_date('04-02-2019', 'DD-MM-YYYY'), 'a', 1, 1, 1);
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2. cases
-- 2.1 split a interval partition, should be successful. and sys_p2 should be changed to range partition
select * from interval_sales partition(sys_p1) order by time_id;
alter table interval_sales split partition sys_p1 at (to_date('2009-02-10', 'YYYY-MM-DD')) into (partition sys_p1_1, partition sys_p1_2);
select * from interval_sales partition(sys_p1_1) order by time_id;
select * from interval_sales partition(sys_p1_2) order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2.2 split a range partition. (this partition has been changed to range partition in previous step)
select * from interval_sales partition(sys_p2) order by time_id;
alter table interval_sales split partition sys_p2 at (to_date('2009-01-10', 'YYYY-MM-DD')) into (partition sys_p2_1, partition sys_p2_2);
select * from interval_sales partition(sys_p2_1) order by time_id;
select * from interval_sales partition(sys_p2_2) order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2.3 split interval partition sys_p3, successful, and no other partitions should be changed.
select * from interval_sales partition(sys_p3) order by time_id;
alter table interval_sales split partition sys_p3 at (to_date('2009-04-5', 'YYYY-MM-DD')) into (partition sys_p3_1, partition sys_p3_2);
select * from interval_sales partition(sys_p3_1) order by time_id;
select * from interval_sales partition(sys_p3_2) order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2.4 split interval partition sys_p4 at its lower bound, should fail.
select * from interval_sales partition(sys_p4) order by time_id;
alter table interval_sales split partition sys_p4 at (to_date('2009-07-6', 'YYYY-MM-DD')) into (partition sys_p4_1, partition sys_p4_2);
select * from interval_sales partition(sys_p4) order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2.5 split interval partition sys_p4 at its upper bound, should fail.
select * from interval_sales partition(sys_p4) order by time_id;
alter table interval_sales split partition sys_p4 at (to_date('2009-08-06', 'YYYY-MM-DD')) into (partition sys_p4_1, partition sys_p4_2);
select * from interval_sales partition(sys_p4) order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2.6 split sys_P4 at a valid point, should be successful, and no other partitions changed.
select * from interval_sales partition(sys_p4) order by time_id;
alter table interval_sales split partition sys_p4 at (to_date('2009-07-10', 'YYYY-MM-DD')) into (partition sys_p4_1, partition sys_p4_2);
select * from interval_sales partition(sys_p4_1) order by time_id;
select * from interval_sales partition(sys_p4_2) order by time_id;
select relname, parttype, rangenum, intervalnum, partstrategy, interval, boundaries from pg_partition
where parentid = (select oid from pg_class where relname = 'interval_sales') order by relname;
-- 2.7.0 split p1 using partition def list, no split point given, first partition invalid, equal to previous partition p0_2's boundaries.
alter table interval_sales split partition p1 into
(partition p1_1 values less than (to_date('2008-01-01', 'YYYY-MM-DD')),
partition p1_2 values less than (to_date('2008-03-06', 'YYYY-MM-DD')),
partition p1_3 values less than (to_date('2008-04-06', 'YYYY-MM-DD')),
partition p1_4 values less than (to_date('2008-05-06', 'YYYY-MM-DD')));
-- 2.7.1 split p1 using partition def list, no split point given, first partition invalid, less than previous partition p0_2's boundaries.
alter table interval_sales split partition p1 into
(partition p1_1 values less than (to_date('2007-01-01', 'YYYY-MM-DD')),
partition p1_2 values less than (to_date('2008-03-06', 'YYYY-MM-DD')),
partition p1_3 values less than (to_date('2008-04-06', 'YYYY-MM-DD')),
partition p1_4 values less than (to_date('2008-05-06', 'YYYY-MM-DD')));
-- 2.7.2 split p1 using partition def list, no split point given, first partition valid, greater than previous partition p0_2's boundaries.
alter table interval_sales split partition p1 into
(partition p1_1 values less than (to_date('2008-01-03', 'YYYY-MM-DD')),
partition p1_2 values less than (to_date('2008-03-06', 'YYYY-MM-DD')),
partition p1_3 values less than (to_date('2008-04-06', 'YYYY-MM-DD')),
partition p1_4 values less than (to_date('2008-05-06', 'YYYY-MM-DD')));
select * from interval_sales partition(p1_1)order by time_id;
select * from interval_sales partition(p1_2)order by time_id;
select * from interval_sales partition(p1_3)order by time_id;
select * from interval_sales partition(p1_4)order by time_id;
-- 2.8.1 split sys_p6 using partition def list, no split point given, first partition invalid, equal to self's lower boundaries.
alter table interval_sales split partition sys_p6 into
(partition sys_p6_1 values less than (to_date('2018-10-6', 'YYYY-MM-DD')),
partition sys_p6_2 values less than (to_date('2018-10-29', 'YYYY-MM-DD')),
partition sys_p6_3 values less than (to_date('2018-11-01', 'YYYY-MM-DD')),
partition sys_p6_4 values less than (to_date('2018-11-06', 'YYYY-MM-DD')));
-- 2.8.2 split sys_p6 using partition def list, no split point given, first partition invalid, less than self's lower boundaries.
alter table interval_sales split partition sys_p6 into
(partition sys_p6_1 values less than (to_date('2018-10-5', 'YYYY-MM-DD')),
partition sys_p6_2 values less than (to_date('2018-10-29', 'YYYY-MM-DD')),
partition sys_p6_3 values less than (to_date('2018-11-01', 'YYYY-MM-DD')),
partition sys_p6_4 values less than (to_date('2018-11-06', 'YYYY-MM-DD')));
-- 2.8.3 split sys_p6 using partition def list, no split point given, first partition valid, greater than self's lower boundaries.
alter table interval_sales split partition sys_p6 into
(partition sys_p6_1 values less than (to_date('2018-10-8', 'YYYY-MM-DD')),
partition sys_p6_2 values less than (to_date('2018-10-29', 'YYYY-MM-DD')),
partition sys_p6_3 values less than (to_date('2018-11-01', 'YYYY-MM-DD')),
partition sys_p6_4 values less than (to_date('2018-11-06', 'YYYY-MM-DD')));
select * from interval_sales partition(sys_p6_1)order by time_id;
select * from interval_sales partition(sys_p6_2)order by time_id;
select * from interval_sales partition(sys_p6_3)order by time_id;
select * from interval_sales partition(sys_p6_4)order by time_id;
-- 3 drop table interval_sales
drop table interval_sales;