From 1b290e06539f5768962c4457605b24197d0ecf50 Mon Sep 17 00:00:00 2001 From: Alexander Korotkov Date: Sun, 7 Apr 2024 00:57:22 +0300 Subject: [PATCH v46 1/2] Implement ALTER TABLE ... MERGE PARTITIONS ... command This new DDL command merges several partitions into the one partition of the target table. The target partition is created using new createPartitionTable() function with parent partition as the template. This commit comprises quite naive implementation which works in single process and holds the ACCESS EXCLUSIVE LOCK on the parent table during all the operations including the tuple routing. This is why this new DDL command can't be recommended for large partitioned tables under a high load. However, this implementation come in handy in certain cases even as is. Also, it could be used as a foundation for future implementations with lesser locking and possibly parallel. Discussion: https://postgr.es/m/c73a1746-0cd0-6bdd-6b23-3ae0b7c0c582%40postgrespro.ru Author: Dmitry Koval Reviewed-by: Matthias van de Meent, Laurenz Albe, Zhihong Yu, Justin Pryzby Reviewed-by: Alvaro Herrera, Robert Haas, Stephane Tachoires, Jian He Fixes (summary information). Authors: Alexander Korotkov, Tender Wang, Richard Guo, Dagfinn Ilmari Mannsaker Authors: Fujii Masao, Jian He Reviewed-by: Alexander Korotkov, Robert Haas, Justin Pryzby, Pavel Borisov Reviewed-by: Masahiko Sawada Reported-by: Alexander Lakhin, Justin Pryzby, Kyotaro Horiguchi Reported-by: Daniel Gustafsson, Tom Lane, Noah Misch --- doc/src/sgml/ddl.sgml | 19 + doc/src/sgml/ref/alter_table.sgml | 104 +- src/backend/catalog/dependency.c | 50 + src/backend/catalog/heap.c | 4 +- src/backend/catalog/pg_constraint.c | 2 +- src/backend/commands/tablecmds.c | 906 +++++++++++- src/backend/parser/gram.y | 22 +- src/backend/parser/parse_utilcmd.c | 148 ++ src/backend/partitioning/partbounds.c | 199 ++- src/bin/psql/tab-complete.in.c | 10 + src/include/catalog/dependency.h | 2 + src/include/catalog/heap.h | 3 + src/include/nodes/parsenodes.h | 5 +- src/include/parser/kwlist.h | 1 + src/include/partitioning/partbounds.h | 6 + .../isolation/expected/partition-merge.out | 199 +++ src/test/isolation/isolation_schedule | 1 + src/test/isolation/specs/partition-merge.spec | 54 + .../test_ddl_deparse/test_ddl_deparse.c | 3 + src/test/regress/expected/partition_merge.out | 1234 +++++++++++++++++ src/test/regress/parallel_schedule | 2 +- src/test/regress/sql/partition_merge.sql | 816 +++++++++++ 22 files changed, 3761 insertions(+), 29 deletions(-) create mode 100644 src/test/isolation/expected/partition-merge.out create mode 100644 src/test/isolation/specs/partition-merge.spec create mode 100644 src/test/regress/expected/partition_merge.out create mode 100644 src/test/regress/sql/partition_merge.sql diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 96936bcd3a..62c2bb54ea 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -4440,6 +4440,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate); ALTER INDEX measurement_city_id_logdate_key ATTACH PARTITION measurement_y2006m02_city_id_logdate_key; ... + + + + + There is also an option for merging multiple table partitions into + a single partition using the + ALTER TABLE ... MERGE PARTITIONS. + This feature simplifies the management of partitioned tables by allowing + users to combine partitions that are no longer needed as + separate entities. It's important to note that this operation is not + supported for hash-partitioned tables and acquires an + ACCESS EXCLUSIVE lock, which could impact high-load + systems due to the lock's restrictive nature. For example, we can + merge three monthly partitions into one quarter partition: + +ALTER TABLE measurement + MERGE PARTITIONS (measurement_y2006m01, + measurement_y2006m02, + measurement_y2006m03) INTO measurement_y2006q1; diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml index d63f3a621a..e503a06028 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -37,6 +37,9 @@ ALTER TABLE [ IF EXISTS ] name ATTACH PARTITION partition_name { FOR VALUES partition_bound_spec | DEFAULT } ALTER TABLE [ IF EXISTS ] name DETACH PARTITION partition_name [ CONCURRENTLY | FINALIZE ] +ALTER TABLE [ IF EXISTS ] name + MERGE PARTITIONS (partition_name1, partition_name2 [, ...]) + INTO partition_name where action is one of: @@ -1147,14 +1150,101 @@ WITH ( MODULUS numeric_literal, REM + + MERGE PARTITIONS (partition_name1, partition_name2 [, ...]) INTO partition_name + + + + This form merges several partitions of the target table into a new partition. + Hash-partitioned target table is not supported. + If DEFAULT partition is not in the + list of partitions partition_name1, + partition_name2 [, ...]: + + + + For range-partitioned tables, the ranges of the partitions + partition_name1, + partition_name2, [...] + must be adjacent in order to be merged. Otherwise, an error will be + raised. The resulting combined range will be the new partition bound + for the partition partition_name. + + + + + For list-partitioned tables, the partition bounds of + partition_name1, + partition_name2, [...] + are combined to form the new partition bound for + partition_name. + + + + If DEFAULT partition is in the list of partitions partition_name1, + partition_name2 [, ...]: + + + + The partition partition_name + will be the new DEFAULT partition of the target table. + + + + + The partition bound specifications for all partitions- + partition_name1, + partition_name2, [...] + can be arbitrary. + + + + The new partition partition_name + can have the same name as one of the merged partitions. Only simple, + non-partitioned partitions can be merged. + + + If merged partitions have different owners, an error will be generated. + The owner of the merged partitions will be the owner of the new partition. + It is the user's responsibility to setup ACL on the + new partition. + + + The indexes and identity are created later, after moving the data + into the new partition. + Extended statistics aren't copied from the parent table, for consistency with + CREATE TABLE PARTITION OF. + The new partition will inherit the same table access method, persistence + type, and tablespace as the parent table. + + + When partitions are merged, any individual objects belonging to those + partitions, such as constraints or statistics will be dropped. This occurs + because ALTER TABLE MERGE PARTITIONS uses the partitioned table itself as the + template to define these objects. + + + If merged partitions have some objects dependent on them, the command can + not be done (CASCADE is not used, an error will be returned). + + + + Merging partitions acquires a ACCESS EXCLUSIVE lock on + the parent table, in addition to the ACCESS EXCLUSIVE + locks on the tables being merged and on the default partition (if any). + + + + + All the forms of ALTER TABLE that act on a single table, except RENAME, SET SCHEMA, - ATTACH PARTITION, and - DETACH PARTITION can be combined into + ATTACH PARTITION, DETACH PARTITION, + and MERGE PARTITIONS can be combined into a list of multiple alterations to be applied together. For example, it is possible to add several columns and/or alter the type of several columns in a single command. This is particularly useful with large @@ -1397,7 +1487,8 @@ WITH ( MODULUS numeric_literal, REM partition_name - The name of the table to attach as a new partition or to detach from this table. + The name of the table to attach as a new partition or to detach from this table, + or the name of the new merged partition. @@ -1830,6 +1921,13 @@ ALTER TABLE measurement DETACH PARTITION measurement_y2015m12; + + To merge several partitions into one partition of the target table: + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) + INTO sales_all; + + diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c index 18316a3968..5afc493820 100644 --- a/src/backend/catalog/dependency.c +++ b/src/backend/catalog/dependency.c @@ -319,6 +319,56 @@ performDeletion(const ObjectAddress *object, table_close(depRel, RowExclusiveLock); } +/* + * performDeletionCheck: Check whether a specific object can be safely deleted. + * This function does not perform any deletion; instead, it raises an error + * if the object cannot be deleted due to existing dependencies. + * + * It can be useful when you need delete some objects later. See comments in + * performDeletion too. + * The behavior must specified as DROP_RESTRICT. + */ +void +performDeletionCheck(const ObjectAddress *object, + DropBehavior behavior, int flags) +{ + Relation depRel; + ObjectAddresses *targetObjects; + + Assert(behavior == DROP_RESTRICT); + + depRel = table_open(DependRelationId, RowExclusiveLock); + + AcquireDeletionLock(object, 0); + + /* + * Construct a list of objects we want delete later (ie, the given object plus + * everything directly or indirectly dependent on it). + */ + targetObjects = new_object_addresses(); + + findDependentObjects(object, + DEPFLAG_ORIGINAL, + flags, + NULL, /* empty stack */ + targetObjects, + NULL, /* no pendingObjects */ + &depRel); + + /* + * Check if deletion is allowed. + */ + reportDependentObjects(targetObjects, + behavior, + flags, + object); + + /* And clean up */ + free_object_addresses(targetObjects); + + table_close(depRel, RowExclusiveLock); +} + /* * performMultipleDeletions: Similar to performDeletion, but act on multiple * objects at once. diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c index fbaed5359a..571b6b0574 100644 --- a/src/backend/catalog/heap.c +++ b/src/backend/catalog/heap.c @@ -105,8 +105,6 @@ static void RelationRemoveInheritance(Oid relid); static Oid StoreRelCheck(Relation rel, const char *ccname, Node *expr, bool is_enforced, bool is_validated, bool is_local, int16 inhcount, bool is_no_inherit, bool is_internal); -static void StoreConstraints(Relation rel, List *cooked_constraints, - bool is_internal); static bool MergeWithExistingConstraint(Relation rel, const char *ccname, Node *expr, bool allow_merge, bool is_local, bool is_enforced, @@ -2296,7 +2294,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum, * expressions can be added later, by direct calls to StoreAttrDefault * and StoreRelCheck (see AddRelationNewConstraints()). */ -static void +void StoreConstraints(Relation rel, List *cooked_constraints, bool is_internal) { int numchecks = 0; diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c index 2d5ac1ea81..1f948876d9 100644 --- a/src/backend/catalog/pg_constraint.c +++ b/src/backend/catalog/pg_constraint.c @@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh) false))); constr->is_enforced = true; constr->skip_validation = !conForm->convalidated; - constr->initially_valid = true; + constr->initially_valid = conForm->convalidated; constr->is_no_inherit = conForm->connoinherit; notnulls = lappend(notnulls, constr); } diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index ea96947d81..9a9053d325 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition); static char GetAttributeCompression(Oid atttypid, const char *compression); static char GetAttributeStorage(Oid atttypid, const char *storagemode); +static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel, + PartitionCmd *cmd, AlterTableUtilityContext *context); /* ---------------------------------------------------------------- * DefineRelation @@ -4834,6 +4836,10 @@ AlterTableGetLockLevel(List *cmds) cmd_lockmode = ShareUpdateExclusiveLock; break; + case AT_MergePartitions: + cmd_lockmode = AccessExclusiveLock; + break; + default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -5269,6 +5275,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, /* No command-specific prep needed */ pass = AT_PASS_MISC; break; + case AT_MergePartitions: + ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE); + /* No command-specific prep needed */ + pass = AT_PASS_MISC; + break; default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -5665,6 +5676,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab, case AT_DetachPartitionFinalize: address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name); break; + case AT_MergePartitions: + cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode, + cur_pass, context); + Assert(cmd != NULL); + Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE); + ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def, + context); + break; default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -6705,6 +6724,8 @@ alter_table_type_to_string(AlterTableType cmdtype) return "DETACH PARTITION"; case AT_DetachPartitionFinalize: return "DETACH PARTITION ... FINALIZE"; + case AT_MergePartitions: + return "MERGE PARTITIONS"; case AT_AddIdentity: return "ALTER COLUMN ... ADD IDENTITY"; case AT_SetIdentity: @@ -20169,6 +20190,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel, } } +/* + * attachPartitionTable: attach a new partition to the partitioned table + * + * wqueue: the ALTER TABLE work queue; can be NULL when not running as part + * of an ALTER TABLE sequence. + * rel: partitioned relation; + * attachrel: relation of attached partition; + * bound: bounds of attached relation. + */ +static void +attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound) +{ + /* OK to create inheritance. Rest of the checks performed there */ + CreateInheritance(attachrel, rel, true); + + /* Update the pg_class entry. */ + StorePartitionBound(attachrel, rel, bound); + + /* Ensure there exists a correct set of indexes in the partition. */ + AttachPartitionEnsureIndexes(wqueue, rel, attachrel); + + /* and triggers */ + CloneRowTriggersToPartition(rel, attachrel); + + /* + * Clone foreign key constraints. Callee is responsible for setting up + * for phase 3 constraint verification. + */ + CloneForeignKeyConstraints(wqueue, rel, attachrel); +} + /* * ALTER TABLE ATTACH PARTITION FOR VALUES * @@ -20372,23 +20424,8 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd, check_new_partition_bound(RelationGetRelationName(attachrel), rel, cmd->bound, pstate); - /* OK to create inheritance. Rest of the checks performed there */ - CreateInheritance(attachrel, rel, true); - - /* Update the pg_class entry. */ - StorePartitionBound(attachrel, rel, cmd->bound); - - /* Ensure there exists a correct set of indexes in the partition. */ - AttachPartitionEnsureIndexes(wqueue, rel, attachrel); - - /* and triggers */ - CloneRowTriggersToPartition(rel, attachrel); - - /* - * Clone foreign key constraints. Callee is responsible for setting up - * for phase 3 constraint verification. - */ - CloneForeignKeyConstraints(wqueue, rel, attachrel); + /* Attach a new partition to the partitioned table. */ + attachPartitionTable(wqueue, rel, attachrel, cmd->bound); /* * Generate partition constraint from the partition bound specification. @@ -22035,3 +22072,838 @@ GetAttributeStorage(Oid atttypid, const char *storagemode) return cstorage; } + + +/* + * buildExpressionExecutionStates: build the needed expression execution states + * for new partition (newPartRel) checks and initialize expressions for + * generated columns. All expressions should be created in "tab" + * (AlteredTableInfo structure). + */ +static void +buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate) +{ + /* Build the needed expression execution states. */ + foreach_ptr(NewConstraint, con, tab->constraints) + { + switch (con->contype) + { + case CONSTR_CHECK: + con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newPartRel, 1), estate); + break; + case CONSTR_FOREIGN: + /* Nothing to do here. */ + break; + case CONSTR_NOTNULL: + /* Nothing to do here. */ + break; + default: + elog(ERROR, "unrecognized constraint type: %d", + (int) con->contype); + } + } + + foreach_ptr(NewColumnValue, ex, tab->newvals) + { + /* Expression already planned. */ + ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL); + } +} + +/* + * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated + * expressions for "tab" (AlteredTableInfo structure) whose inputs come from + * the new tuple (insertslot) of new partition (newPartRel). + */ +static void +evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab, + Relation newPartRel, + TupleTableSlot *insertslot, + ExprContext *econtext) +{ + econtext->ecxt_scantuple = insertslot; + + foreach_ptr(NewColumnValue, ex, tab->newvals) + { + if (!ex->is_generated) + continue; + + insertslot->tts_values[ex->attnum - 1] + = ExecEvalExpr(ex->exprstate, + econtext, + &insertslot->tts_isnull[ex->attnum - 1]); + } + + foreach_ptr(NewConstraint, con, tab->constraints) + { + switch (con->contype) + { + case CONSTR_CHECK: + if (!ExecCheck(con->qualstate, econtext)) + ereport(ERROR, + errcode(ERRCODE_CHECK_VIOLATION), + errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row", + con->name, RelationGetRelationName(newPartRel)), + errtableconstraint(newPartRel, con->name)); + break; + case CONSTR_NOTNULL: + case CONSTR_FOREIGN: + /* Nothing to do here */ + break; + default: + elog(ERROR, "unrecognized constraint type: %d", + (int) con->contype); + } + } +} + +/* + * getAttributesList: return list of columns (ColumnDef) like model table + * (modelRel) + */ +static List * +getAttributesList(Relation modelRel) +{ + AttrNumber parent_attno; + TupleDesc modelDesc; + List *colList = NIL; + + modelDesc = RelationGetDescr(modelRel); + + for (parent_attno = 1; parent_attno <= modelDesc->natts; + parent_attno++) + { + Form_pg_attribute attribute = TupleDescAttr(modelDesc, + parent_attno - 1); + ColumnDef *def; + + /* Ignore dropped columns in the parent. */ + if (attribute->attisdropped) + continue; + + def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid, + attribute->atttypmod, attribute->attcollation); + + def->is_not_null = attribute->attnotnull; + + /* Copy identity for new partition. */ + def->identity = attribute->attidentity; + + /* Add to column list */ + colList = lappend(colList, def); + + /* + * Although we don't transfer the column's default/generation + * expression now, we need to mark it GENERATED if appropriate. + */ + if (attribute->atthasdef && attribute->attgenerated) + def->generated = attribute->attgenerated; + + def->storage = attribute->attstorage; + + /* Likewise, copy compression if requested */ + if (CompressionMethodIsValid(attribute->attcompression)) + def->compression = + pstrdup(GetCompressionMethodName(attribute->attcompression)); + else + def->compression = NULL; + } + + return colList; +} + + +/* + * createTableConstraints: create constraints, default values and generated + * values (prototype is function expandTableLikeClause). + * tab is pending-work queue for newRel, we may need it in moveMergedTablesRows. + */ +static void +createTableConstraints(List **wqueue, AlteredTableInfo *tab, + Relation modelRel, Relation newRel) +{ + TupleDesc tupleDesc; + TupleConstr *constr; + AttrMap *attmap; + AttrNumber parent_attno; + int ccnum; + List *cookedConstraints = NIL; + + tupleDesc = RelationGetDescr(modelRel); + constr = tupleDesc->constr; + + if (!constr) + return; + + /* + * Construct a map from the LIKE relation's attnos to the child rel's. + * This re-checks type match etc, although it shouldn't be possible to + * have a failure since both tables are locked. + */ + attmap = build_attrmap_by_name(RelationGetDescr(newRel), + tupleDesc, + false); + + /* Cycle for default values. */ + for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++) + { + Form_pg_attribute attribute = TupleDescAttr(tupleDesc, + parent_attno - 1); + + /* Ignore dropped columns in the parent. */ + if (attribute->attisdropped) + continue; + + /* Copy default, if present and it should be copied. */ + if (attribute->atthasdef) + { + Node *this_default = NULL; + bool found_whole_row; + AttrNumber num; + Node *def; + NewColumnValue *newval; + + if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL) + this_default = build_generation_expression(modelRel, attribute->attnum); + else + { + this_default = TupleDescGetDefault(tupleDesc, attribute->attnum); + if (this_default == NULL) + elog(ERROR, "default expression not found for attribute %d of relation \"%s\"", + attribute->attnum, RelationGetRelationName(modelRel)); + } + + num = attmap->attnums[parent_attno - 1]; + def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row); + + /* + * Prevent this for the same reason as for constraints below. Note + * that defaults cannot contain any vars, so it's OK that the + * error message refers to generated columns. + */ + if (found_whole_row && attribute->attgenerated != '\0') + ereport(ERROR, + errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot convert whole-row table reference"), + errdetail("Generation expression for column \"%s\" contains a whole-row reference to table \"%s\".", + NameStr(attribute->attname), + RelationGetRelationName(modelRel))); + + /* Add a pre-cooked default expression. */ + StoreAttrDefault(newRel, num, def, true); + + /* + * Stored generated column expressions in modelRel might reference + * tableoid. newRel, modelRel tableoid clear is not the same. If + * so, these stored generated columns require recomputation for + * newRel within moveMergedTablesRows. + */ + if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED) + { + newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue)); + newval->attnum = num; + newval->expr = expression_planner((Expr *) def); + newval->is_generated = (attribute->attgenerated != '\0'); + tab->newvals = lappend(tab->newvals, newval); + } + } + } + + /* Cycle for CHECK constraints. */ + for (ccnum = 0; ccnum < constr->num_check; ccnum++) + { + char *ccname = constr->check[ccnum].ccname; + char *ccbin = constr->check[ccnum].ccbin; + bool ccenforced = constr->check[ccnum].ccenforced; + bool ccnoinherit = constr->check[ccnum].ccnoinherit; + bool ccvalid = constr->check[ccnum].ccvalid; + Node *ccbin_node; + bool found_whole_row; + CookedConstraint *cooked; + + /* + * Partitioned table can not have NO INHERIT check constraint (see + * StoreRelCheck function). + */ + Assert(!ccnoinherit); + + ccbin_node = map_variable_attnos(stringToNode(ccbin), + 1, 0, + attmap, + InvalidOid, &found_whole_row); + + /* + * We reject whole-row variables because the whole point of LIKE is + * that the new table's rowtype might later diverge from the parent's. + * So, while translation might be possible right now, it wouldn't be + * possible to guarantee it would work in future. + */ + if (found_whole_row) + ereport(ERROR, + errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot convert whole-row table reference"), + errdetail("Constraint \"%s\" contains a whole-row reference to table \"%s\".", + ccname, + RelationGetRelationName(modelRel))); + + cooked = (CookedConstraint *) palloc(sizeof(CookedConstraint)); + cooked->contype = CONSTR_CHECK; + cooked->conoid = InvalidOid; + cooked->name = ccname; + cooked->attnum = 0; + cooked->expr = ccbin_node; + cooked->is_enforced = ccenforced; + cooked->skip_validation = !ccvalid; + cooked->is_local = true; + cooked->inhcount = 0; + cooked->is_no_inherit = ccnoinherit; + cookedConstraints = lappend(cookedConstraints, cooked); + } + + /* Store CHECK constraints. */ + StoreConstraints(newRel, cookedConstraints, true); + + /* + * modelRel check constraint expresssion may reference tableoid, so later in + * moveMergedTablesRows, we need evulate the check constraint again for the + * newRel. We can check weather check constraint contain tableoid reference + * or not via pull_varattnos. + */ + foreach_ptr(CookedConstraint, ccon, cookedConstraints) + { + if (!ccon->skip_validation && ccon->contype == CONSTR_CHECK) + { + Node *qual; + Bitmapset *attnums = NULL; + + qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1); + pull_varattnos(qual, 1, &attnums); + + /* + * Add check only if it contains tableoid + * (TableOidAttributeNumber). + */ + if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber, + attnums)) + { + NewConstraint *newcon; + + newcon = (NewConstraint *) palloc0(sizeof(NewConstraint)); + newcon->name = ccon->name; + newcon->contype = ccon->contype; + newcon->qual = qual; + + tab->constraints = lappend(tab->constraints, newcon); + } + } + } + + /* Don't need the cookedConstraints any more. */ + list_free_deep(cookedConstraints); + + /* Reproduce not-null constraints. */ + if (constr->has_not_null) + { + List *nnconstraints; + + /* + * The "include_noinh" argument is false because a partitioned table + * cannot have NO INHERIT constraint. + */ + nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(modelRel), + false, false); + + Assert(list_length(nnconstraints) > 0); + + /* + * We already set pg_attribute.attnotnull in createPartitionTable. No + * need call set_attnotnull again. + */ + AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL); + } +} + + +/* + * createPartitionTable: create table for a new partition with given name + * (newPartName) like table (modelRel, partitioned table). ownerId is + * determined by the partition on which the operation is performed, so it + * is passed separately. + * + * Also, this function sets the new partition access method same as parent + * table access methods (similarly to CREATE TABLE ... PARTITION OF). It + * checks that parent and child tables have compatible persistence. + * + * Function returns the created relation (locked in AccessExclusiveLock mode). + */ +static Relation +createPartitionTable(List **wqueue, RangeVar *newPartName, + Relation modelRel, Oid ownerId) +{ + Relation newRel; + Oid newRelId; + Oid existingRelid; + TupleDesc descriptor; + List *colList = NIL; + Oid relamId; + Oid namespaceId; + AlteredTableInfo *new_partrel_tab; + + /* If existing rel is temp, it must belong to this session */ + if (RELATION_IS_OTHER_TEMP(modelRel)) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create as partition of temporary relation of another session")); + + /* Look up inheritance ancestors and generate relation schema. */ + colList = getAttributesList(modelRel); + + /* Create a tuple descriptor from the relation schema. */ + descriptor = BuildDescForRelation(colList); + + /* Look up the access method for new relation. */ + relamId = (modelRel->rd_rel->relam != InvalidOid) ? modelRel->rd_rel->relam : HEAP_TABLE_AM_OID; + + /* Look up the namespace in which we are supposed to create the relation. */ + namespaceId = + RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid); + if (OidIsValid(existingRelid)) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("relation \"%s\" already exists", newPartName->relname)); + + /* Create the relation. */ + newRelId = heap_create_with_catalog(newPartName->relname, + namespaceId, + modelRel->rd_rel->reltablespace, + InvalidOid, + InvalidOid, + InvalidOid, + ownerId, + relamId, + descriptor, + NIL, + RELKIND_RELATION, + newPartName->relpersistence, + false, + false, + ONCOMMIT_NOOP, + (Datum) 0, + true, + allowSystemTableMods, + false, + InvalidOid, + NULL); + + /* + * We must bump the command counter to make the newly-created relation + * tuple visible for opening. + */ + CommandCounterIncrement(); + + /* + * Open the new partition with no lock, because we already have + * AccessExclusiveLock placed there after creation. + */ + newRel = table_open(newRelId, NoLock); + + /* Find or create work queue entry for newly created table. */ + new_partrel_tab = ATGetQueueEntry(wqueue, newRel); + + /* + * We intended to create the partition with the same persistence as the + * parent table, but we still need to recheck because that might be + * affected by the search_path. If the parent is permanent, so must be + * all of its partitions. + */ + if (modelRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP && + newRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"", + RelationGetRelationName(modelRel))); + + /* Permanent rels cannot be partitions belonging to temporary parent */ + if (newRel->rd_rel->relpersistence != RELPERSISTENCE_TEMP && + modelRel->rd_rel->relpersistence == RELPERSISTENCE_TEMP) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"", + RelationGetRelationName(modelRel))); + + /* Create constraints, default values and generated values */ + createTableConstraints(wqueue, new_partrel_tab, modelRel, newRel); + + /* + * Need to call CommandCounterIncrement, so fresh relcache entry have newly + * installed constraint info. + */ + CommandCounterIncrement(); + + return newRel; +} + +/* + * moveMergedTablesRows: scan partitions to be merged (mergingPartitions) + * of the partitioned table (rel) and move rows into the new partition + * (newPartRel). We also reevaulate check constraints against these rows. + */ +static void +moveMergedTablesRows(List **wqueue, Relation rel, + List *mergingPartitions, Relation newPartRel) +{ + CommandId mycid; + EState *estate; + ExprContext *econtext; + AlteredTableInfo *tab; + ListCell *ltab; + + /* The FSM is empty, so don't bother using it. */ + int ti_options = TABLE_INSERT_SKIP_FSM; + BulkInsertState bistate; /* state of bulk inserts for partition */ + TupleTableSlot *dstslot; + + /* Find the work queue entry for new partition table: newPartRel. */ + tab = ATGetQueueEntry(wqueue, newPartRel); + + /* Generate the constraint and default execution states. */ + estate = CreateExecutorState(); + + buildExpressionExecutionStates(tab, newPartRel, estate); + + econtext = GetPerTupleExprContext(estate); + + mycid = GetCurrentCommandId(true); + + /* Prepare a BulkInsertState for table_tuple_insert. */ + bistate = GetBulkInsertState(); + + /* Create necessary tuple slot. */ + dstslot = table_slot_create(newPartRel, NULL); + + foreach_oid(merging_oid, mergingPartitions) + { + TupleTableSlot *srcslot; + TupleConversionMap *tuple_map; + TableScanDesc scan; + Snapshot snapshot; + Relation mergingPartition; + + /* + * Partition is already locked in the transformPartitionCmdForMerge + * function. + */ + mergingPartition = table_open(merging_oid, NoLock); + + /* Create tuple slot for new partition. */ + srcslot = table_slot_create(mergingPartition, NULL); + + /* + * Map computing for moving attributes of merged partition to new + * partition. + */ + tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition), + RelationGetDescr(newPartRel)); + + /* Scan through the rows. */ + snapshot = RegisterSnapshot(GetLatestSnapshot()); + scan = table_beginscan(mergingPartition, snapshot, 0, NULL); + + while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot)) + { + TupleTableSlot *insertslot; + + CHECK_FOR_INTERRUPTS(); + + if (tuple_map) + { + /* Need to use map to copy attributes. */ + insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot); + } + else + { + slot_getallattrs(srcslot); + + /* Copy attributes directly. */ + insertslot = dstslot; + + ExecClearTuple(insertslot); + + memcpy(insertslot->tts_values, srcslot->tts_values, + sizeof(Datum) * srcslot->tts_nvalid); + memcpy(insertslot->tts_isnull, srcslot->tts_isnull, + sizeof(bool) * srcslot->tts_nvalid); + + ExecStoreVirtualTuple(insertslot); + } + + /* + * Constraints and GENERATED expressions might reference the + * tableoid column, so fill tts_tableOid with the desired + * value. (We must do this each time, because it gets + * overwritten with newrel's OID during storing.) + */ + insertslot->tts_tableOid = RelationGetRelid(newPartRel); + + /* + * Now, evaluate any generated expressions whose inputs come from + * the new tuple. We assume these columns won't reference each + * other, so that there's no ordering dependency. + */ + evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel, + insertslot, econtext); + + /* Write the tuple out to the new relation. */ + table_tuple_insert(newPartRel, insertslot, mycid, + ti_options, bistate); + + ResetExprContext(econtext); + } + + table_endscan(scan); + UnregisterSnapshot(snapshot); + + if (tuple_map) + free_conversion_map(tuple_map); + + ExecDropSingleTupleTableSlot(srcslot); + table_close(mergingPartition, NoLock); + } + + FreeExecutorState(estate); + ExecDropSingleTupleTableSlot(dstslot); + FreeBulkInsertState(bistate); + + table_finish_bulk_insert(newPartRel, ti_options); + + /* + * We don't need process this newPartRel since we already processed in here, + * so delete the ALTER TABLE queue of it. + */ + foreach(ltab, *wqueue) + { + tab = (AlteredTableInfo *) lfirst(ltab); + if (tab->relid == RelationGetRelid(newPartRel)) + *wqueue = list_delete_cell(*wqueue, ltab); + } +} + +/* + * detachPartitionTable: detach partition "child_rel" from partitioned table + * "parent_rel" with default partition identifier "defaultPartOid" + */ +static void +detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid) +{ + /* Remove the pg_inherits row first. */ + RemoveInheritance(child_rel, parent_rel, false); + + /* + * Detaching the partition might involve TOAST table access, so ensure we + * have a valid snapshot. + */ + PushActiveSnapshot(GetTransactionSnapshot()); + + /* Do the final part of detaching. */ + DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid); + + PopActiveSnapshot(); +} + +/* + * ALTER TABLE MERGE PARTITIONS INTO + */ +static void +ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel, + PartitionCmd *cmd, AlterTableUtilityContext *context) +{ + Relation newPartRel; + List *mergingPartitions = NIL; + Oid defaultPartOid; + Oid existingRelid; + Oid ownerId = InvalidOid; + Oid save_userid; + int save_sec_context; + int save_nestlevel; + + /* + * Check ownership of merged partitions — partitions with different owners + * cannot be merged. Also, collect the OIDs of these partitions during the + * check. + */ + foreach_node(RangeVar, name, cmd->partlist) + { + Relation mergingPartition; + + /* + * We are going to detach and remove this partition. We already took + * AccessExclusiveLock lock on transformPartitionCmdForMerge, so here, + * NoLock is fine. + */ + mergingPartition = table_openrv_extended(name, NoLock, false); + Assert(CheckRelationLockedByMe(mergingPartition, AccessExclusiveLock, false)); + + if (OidIsValid(ownerId)) + { + /* Do the partitions being merged have different owners? */ + if (ownerId != mergingPartition->rd_rel->relowner) + ereport(ERROR, + errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("partitions being merged have different owners")); + } + else + ownerId = mergingPartition->rd_rel->relowner; + + /* Store a next merging partition into the list. */ + mergingPartitions = lappend_oid(mergingPartitions, + RelationGetRelid(mergingPartition)); + + table_close(mergingPartition, NoLock); + } + + /* + * Look up existing relation by new partition name, check we have + * permission to create there, lock it against concurrent drop, and mark + * stmt->relation as RELPERSISTENCE_TEMP if a temporary namespace is + * selected. + */ + cmd->name->relpersistence = rel->rd_rel->relpersistence; + RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid); + + /* + * Check if this name is already taken. This helps us to detect the + * situation when one of the merging partitions has the same name as the + * new partition. Otherwise, this would fail later on anyway but catching + * this here allows us to emit a nicer error message. + */ + if (OidIsValid(existingRelid)) + { + Oid newPartitionOid = InvalidOid; + + foreach_oid(mergingPartitionOid, mergingPartitions) + { + if (mergingPartitionOid == existingRelid) + { + newPartitionOid = mergingPartitionOid; + break; + } + } + + if (OidIsValid(newPartitionOid)) + { + /* + * The new partition has the same name as one of merging + * partitions. + */ + char tmpRelName[NAMEDATALEN]; + + /* Generate temporary name. */ + sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid); + + /* + * Rename the existing partition with a temporary name, leaving it + * free for the new partition. We don't need to care about this + * in the future because we're going to eventually drop the + * existing partition anyway. + */ + RenameRelationInternal(newPartitionOid, tmpRelName, true, false); + + /* + * We must bump the command counter to make the new partition + * tuple visible for rename. + */ + CommandCounterIncrement(); + } + else + { + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("relation \"%s\" already exists", cmd->name->relname)); + } + } + + defaultPartOid = + get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true)); + + /* + * Detach all merged partitions. + * + * Perform a preliminary check to determine whether it's safe to drop all + * merging partitions before we actually do so later. After merging rows + * into the new partitions via moveMergedTablesRows, all old partitions need + * be dropped. However, since the drop behavior is DROP_RESTRICT and the + * merge process (moveMergedTablesRows) can be time-consuming, performing an + * early check on the drop eligibility of old partitions is preferable. + */ + foreach_oid(mergingPartitionOid, mergingPartitions) + { + Relation child_rel; + + child_rel = table_open(mergingPartitionOid, NoLock); + + detachPartitionTable(rel, child_rel, defaultPartOid); + + table_close(child_rel, NoLock); + } + + foreach_oid(mergingPartitionOid, mergingPartitions) + { + ObjectAddress object; + + /* Get oid of the later to be dropped relation */ + object.objectId = mergingPartitionOid; + object.classId = RelationRelationId; + object.objectSubId = 0; + + performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL); + } + + /* Create table for new partition, use partitioned table as model. */ + Assert(OidIsValid(ownerId)); + newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId); + + /* + * Switch to the table owner's userid, so that any index functions are run + * as that user. Also lock down security-restricted operations and + * arrange to make GUC variable changes local to this command. + * + * Need to do it after determine namespace in createPartitionTable call. + */ + GetUserIdAndSecContext(&save_userid, &save_sec_context); + SetUserIdAndSecContext(ownerId, + save_sec_context | SECURITY_RESTRICTED_OPERATION); + save_nestlevel = NewGUCNestLevel(); + RestrictSearchPath(); + + /* Copy data from merged partitions to new partition. */ + moveMergedTablesRows(wqueue, rel, mergingPartitions, newPartRel); + + /* Drop the current partitions before attaching the new one. */ + foreach_oid(mergingPartitionOid, mergingPartitions) + { + ObjectAddress object; + + object.objectId = mergingPartitionOid; + object.classId = RelationRelationId; + object.objectSubId = 0; + + performDeletion(&object, DROP_RESTRICT, 0); + } + + list_free(mergingPartitions); + + /* + * Attach a new partition to the partitioned table. wqueue = NULL: + * verification for each cloned constraint is not needed. + */ + attachPartitionTable(NULL, rel, newPartRel, cmd->bound); + + /* Keep the lock until commit. */ + table_close(newPartRel, NoLock); + + /* Roll back any GUC changes executed by index functions. */ + AtEOXact_GUC(false, save_nestlevel); + + /* Restore userid and security context. */ + SetUserIdAndSecContext(save_userid, save_sec_context); +} diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 50f53159d5..46bbdcbc74 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -755,7 +755,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); ORDER ORDINALITY OTHERS OUT_P OUTER_P OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER - PARALLEL PARAMETER PARSER PARTIAL PARTITION PASSING PASSWORD PATH + PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH PERIOD PLACING PLAN PLANS POLICY POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION @@ -2331,6 +2331,7 @@ partition_cmd: n->subtype = AT_AttachPartition; cmd->name = $3; cmd->bound = $4; + cmd->partlist = NIL; cmd->concurrent = false; n->def = (Node *) cmd; @@ -2345,6 +2346,7 @@ partition_cmd: n->subtype = AT_DetachPartition; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NIL; cmd->concurrent = $4; n->def = (Node *) cmd; @@ -2358,6 +2360,21 @@ partition_cmd: n->subtype = AT_DetachPartitionFinalize; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NIL; + cmd->concurrent = false; + n->def = (Node *) cmd; + $$ = (Node *) n; + } + /* ALTER TABLE MERGE PARTITIONS () INTO */ + | MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name + { + AlterTableCmd *n = makeNode(AlterTableCmd); + PartitionCmd *cmd = makeNode(PartitionCmd); + + n->subtype = AT_MergePartitions; + cmd->name = $7; + cmd->bound = NULL; + cmd->partlist = $4; cmd->concurrent = false; n->def = (Node *) cmd; $$ = (Node *) n; @@ -2374,6 +2391,7 @@ index_partition_cmd: n->subtype = AT_AttachPartition; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NIL; cmd->concurrent = false; n->def = (Node *) cmd; @@ -17876,6 +17894,7 @@ unreserved_keyword: | PARSER | PARTIAL | PARTITION + | PARTITIONS | PASSING | PASSWORD | PATH @@ -18503,6 +18522,7 @@ bare_label_keyword: | PARSER | PARTIAL | PARTITION + | PARTITIONS | PASSING | PASSWORD | PATH diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c index 62015431fd..f55ad17528 100644 --- a/src/backend/parser/parse_utilcmd.c +++ b/src/backend/parser/parse_utilcmd.c @@ -32,6 +32,7 @@ #include "catalog/heap.h" #include "catalog/index.h" #include "catalog/namespace.h" +#include "catalog/partition.h" #include "catalog/pg_am.h" #include "catalog/pg_collation.h" #include "catalog/pg_constraint.h" @@ -58,6 +59,8 @@ #include "parser/parse_type.h" #include "parser/parse_utilcmd.h" #include "parser/parser.h" +#include "partitioning/partdesc.h" +#include "partitioning/partbounds.h" #include "rewrite/rewriteManip.h" #include "utils/acl.h" #include "utils/builtins.h" @@ -3488,6 +3491,138 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString, } +/* + * checkPartition + * Check whether partRelOid is a leaf partition of the parent table (rel). + * Partition with OID partRelOid must be locked before function call. + */ +static void +checkPartition(Relation rel, Oid partRelOid) +{ + Relation partRel; + + partRel = table_open(partRelOid, NoLock); + + if (partRel->rd_rel->relkind != RELKIND_RELATION) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)), + errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")); + + if (!partRel->rd_rel->relispartition) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("\"%s\" is not a partition of partitioned table \"%s\"", + RelationGetRelationName(partRel), RelationGetRelationName(rel)), + errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")); + + if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel)) + ereport(ERROR, + errcode(ERRCODE_UNDEFINED_TABLE), + errmsg("relation \"%s\" is not a partition of relation \"%s\"", + RelationGetRelationName(partRel), RelationGetRelationName(rel)), + errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")); + + table_close(partRel, NoLock); +} + +/* + * transformPartitionCmdForMerge + * Analyze the ALTER TABLE ... MERGE PARTITIONS command + * + * Does simple checks for merged partitions. Calculates bound of resulting + * partition. + */ +static void +transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd) +{ + Oid defaultPartOid; + Oid partOid; + Relation parent = cxt->rel; + PartitionKey key; + char strategy; + ListCell *listptr, + *listptr2; + bool isDefaultPart = false; + List *partOids = NIL; + + key = RelationGetPartitionKey(parent); + strategy = get_partition_strategy(key); + + if (strategy == PARTITION_STRATEGY_HASH) + ereport(ERROR, + errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("partition of hash-partitioned table cannot be merged")); + + /* Is current partition a DEFAULT partition? */ + defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true)); + + foreach(listptr, partcmd->partlist) + { + RangeVar *name = (RangeVar *) lfirst(listptr); + + /* Partitions in the list should have different names. */ + for_each_cell(listptr2, partcmd->partlist, lnext(partcmd->partlist, listptr)) + { + RangeVar *name2 = (RangeVar *) lfirst(listptr2); + + if (equal(name, name2)) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("partition with name \"%s\" is already used", name->relname), + parser_errposition(cxt->pstate, name2->location)); + } + + /* + * Search DEFAULT partition in the list. Open and lock partitions before + * calculating the boundary for resulting partition, we also check for + * ownership along the way. We need to use AccessExclusiveLock here, + * because these merged partitions will be detached then dropped in + * ATExecMergePartitions. + */ + partOid = RangeVarGetRelidExtended(name, + AccessExclusiveLock, + false, + RangeVarCallbackOwnsRelation, + NULL); + + if (partOid == defaultPartOid) + isDefaultPart = true; + + /* + * Extended check because the same partition can have different names + * (for example, "part_name" and "public.part_name"). + */ + foreach(listptr2, partOids) + { + Oid curOid = lfirst_oid(listptr2); + + if (curOid == partOid) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("partition with name \"%s\" is already used", name->relname), + parser_errposition(cxt->pstate, name->location)); + } + + checkPartition(parent, partOid); + + partOids = lappend_oid(partOids, partOid); + } + + /* Allocate bound of resulting partition. */ + Assert(partcmd->bound == NULL); + partcmd->bound = makeNode(PartitionBoundSpec); + + /* Fill partition bound. */ + partcmd->bound->strategy = strategy; + partcmd->bound->location = -1; + partcmd->bound->is_default = isDefaultPart; + if (!isDefaultPart) + calculate_partition_bound_for_merge(parent, partcmd->partlist, + partOids, partcmd->bound, + cxt->pstate); +} + /* * transformAlterTableStmt - * parse analysis for ALTER TABLE @@ -3765,6 +3900,19 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt, newcmds = lappend(newcmds, cmd); break; + case AT_MergePartitions: + { + PartitionCmd *partcmd = (PartitionCmd *) cmd->def; + + if (list_length(partcmd->partlist) < 2) + ereport(ERROR, + errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("list of new partitions should contain at least two items")); + transformPartitionCmdForMerge(&cxt, partcmd); + newcmds = lappend(newcmds, cmd); + break; + } + default: /* diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c index 4bdc2941ef..9f7c01b7fa 100644 --- a/src/backend/partitioning/partbounds.c +++ b/src/backend/partitioning/partbounds.c @@ -3214,8 +3214,9 @@ check_new_partition_bound(char *relname, Relation parent, PartitionRangeDatum *datum; /* - * Point to problematic key in the lower datums list; - * if we have equality, point to the first one. + * Point to problematic key in the list of lower + * datums; if we have equality, point to the first + * one. */ datum = cmpval == 0 ? linitial(spec->lowerdatums) : list_nth(spec->lowerdatums, abs(cmpval) - 1); @@ -4977,3 +4978,197 @@ satisfies_hash_partition(PG_FUNCTION_ARGS) PG_RETURN_BOOL(rowHash % modulus == remainder); } + +/* + * check_two_partitions_bounds_range + * + * (function for BY RANGE partitioning) + * + * This is a helper function for calculate_partition_bound_for_merge(). + * This function compares upper bound of first_bound and lower bound of + * second_bound. These bounds should be equal. + * + * parent: partitioned table + * first_name: name of first partition + * first_bound: bound of first partition + * second_name: name of second partition + * second_bound: bound of second partition + * pstate: pointer to ParseState struct for determining error position + */ +static void +check_two_partitions_bounds_range(Relation parent, + RangeVar *first_name, + PartitionBoundSpec *first_bound, + RangeVar *second_name, + PartitionBoundSpec *second_bound, + ParseState *pstate) +{ + PartitionKey key = RelationGetPartitionKey(parent); + PartitionRangeBound *first_upper; + PartitionRangeBound *second_lower; + int cmpval; + + Assert(key->strategy == PARTITION_STRATEGY_RANGE); + + first_upper = make_one_partition_rbound(key, -1, first_bound->upperdatums, false); + second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true); + + /* + * lower1=false (the second to last argument) for correct comparison of + * lower and upper bounds. + */ + cmpval = partition_rbound_cmp(key->partnatts, + key->partsupfunc, + key->partcollation, + second_lower->datums, second_lower->kind, + false, first_upper); + if (cmpval) + { + PartitionRangeDatum *datum = linitial(second_bound->lowerdatums); + + ereport(ERROR, + errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"", + second_name->relname, first_name->relname), + errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."), + parser_errposition(pstate, datum->location)); + } +} + +/* + * get_partition_bound_spec + * + * Returns the PartitionBoundSpec for the partition with the given OID partOid. + */ +static PartitionBoundSpec * +get_partition_bound_spec(Oid partOid) +{ + HeapTuple tuple; + Datum datum; + bool isnull; + PartitionBoundSpec *boundspec = NULL; + + /* Try fetching the tuple from the catcache, for speed. */ + tuple = SearchSysCache1(RELOID, partOid); + if (!HeapTupleIsValid(tuple)) + elog(ERROR, "cache lookup failed for relation %u", partOid); + + datum = SysCacheGetAttr(RELOID, tuple, + Anum_pg_class_relpartbound, + &isnull); + if (isnull) + elog(ERROR, "partition bound for relation %u is null", + partOid); + + boundspec = stringToNode(TextDatumGetCString(datum)); + + if (!IsA(boundspec, PartitionBoundSpec)) + elog(ERROR, "expected PartitionBoundSpec for relation %u", + partOid); + + ReleaseSysCache(tuple); + return boundspec; +} + +/* + * calculate_partition_bound_for_merge + * + * Calculates the bound of merged partition "spec" by using the bounds of + * partitions to be merged. + * + * parent: partitioned table + * partNames: names of partitions to be merged + * partOids: Oids of partitions to be merged + * spec (out): bounds specification of the merged partition + * pstate: pointer to ParseState struct for determine error position + */ +void +calculate_partition_bound_for_merge(Relation parent, + List *partNames, + List *partOids, + PartitionBoundSpec *spec, + ParseState *pstate) +{ + PartitionKey key = RelationGetPartitionKey(parent); + PartitionBoundSpec *bound; + + Assert(!spec->is_default); + + switch (key->strategy) + { + case PARTITION_STRATEGY_RANGE: + { + int i; + PartitionRangeBound **lower_bounds; + int nparts = list_length(partOids); + List *bounds = NIL; + + lower_bounds = (PartitionRangeBound **) + palloc0(nparts * sizeof(PartitionRangeBound *)); + + /* + * Create array of lower bounds and list of + * PartitionBoundSpec. + */ + foreach_oid(partoid, partOids) + { + bound = get_partition_bound_spec(partoid); + i = foreach_current_index(partoid); + + lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true); + bounds = lappend(bounds, bound); + } + + /* Sort array of lower bounds. */ + qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *), + qsort_partition_rbound_cmp, (void *) key); + + /* Ranges of partitions should not overlap. */ + for (i = 1; i < nparts; i++) + { + int index = lower_bounds[i]->index; + int prev_index = lower_bounds[i - 1]->index; + + check_two_partitions_bounds_range(parent, + (RangeVar *) list_nth(partNames, prev_index), + (PartitionBoundSpec *) list_nth(bounds, prev_index), + (RangeVar *) list_nth(partNames, index), + (PartitionBoundSpec *) list_nth(bounds, index), + pstate); + } + + /* + * Lower bound of first partition is the lower bound of merged + * partition. + */ + spec->lowerdatums = + ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums; + + /* + * Upper bound of last partition is the upper bound of merged + * partition. + */ + spec->upperdatums = + ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[nparts - 1]->index))->upperdatums; + + pfree(lower_bounds); + list_free(bounds); + break; + } + + case PARTITION_STRATEGY_LIST: + { + /* Consolidate bounds for all partitions in the list. */ + foreach_oid(partoid, partOids) + { + bound = get_partition_bound_spec(partoid); + spec->listdatums = list_concat(spec->listdatums, bound->listdatums); + } + break; + } + + default: + elog(ERROR, "unexpected partition strategy: %d", + (int) key->strategy); + } +} diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c index 2c0b4f28c1..64248b5b1f 100644 --- a/src/bin/psql/tab-complete.in.c +++ b/src/bin/psql/tab-complete.in.c @@ -2721,6 +2721,7 @@ match_previous_words(int pattern_id, "OWNER TO", "SET", "VALIDATE CONSTRAINT", "REPLICA IDENTITY", "ATTACH PARTITION", "DETACH PARTITION", "FORCE ROW LEVEL SECURITY", + "MERGE PARTITIONS (", "OF", "NOT OF"); /* ALTER TABLE xxx ADD */ else if (Matches("ALTER", "TABLE", MatchAny, "ADD")) @@ -2987,6 +2988,15 @@ match_previous_words(int pattern_id, else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny)) COMPLETE_WITH("CONCURRENTLY", "FINALIZE"); + /* ALTER TABLE MERGE PARTITIONS ( */ + else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(")) + { + set_completion_reference(prev4_wd); + COMPLETE_WITH_SCHEMA_QUERY(Query_for_partition_of_table); + } + else if (Matches("ALTER", "TABLE", MatchAny, "MERGE", "PARTITIONS", "(*)")) + COMPLETE_WITH("INTO"); + /* ALTER TABLE OF */ else if (Matches("ALTER", "TABLE", MatchAny, "OF")) COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_composite_datatypes); diff --git a/src/include/catalog/dependency.h b/src/include/catalog/dependency.h index 0ea7ccf524..f54233499b 100644 --- a/src/include/catalog/dependency.h +++ b/src/include/catalog/dependency.h @@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object); extern void performDeletion(const ObjectAddress *object, DropBehavior behavior, int flags); +extern void performDeletionCheck(const ObjectAddress *object, + DropBehavior behavior, int flags); extern void performMultipleDeletions(const ObjectAddresses *objects, DropBehavior behavior, int flags); diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h index dbd339e9df..c130bc0c38 100644 --- a/src/include/catalog/heap.h +++ b/src/include/catalog/heap.h @@ -119,6 +119,9 @@ extern List *AddRelationNotNullConstraints(Relation rel, List *constraints, List *old_notnulls); +extern void StoreConstraints(Relation rel, List *cooked_constraints, + bool is_internal); + extern void RelationClearMissing(Relation rel); extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum, diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index ba12678d1c..b8e2a679cd 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -969,8 +969,10 @@ typedef struct PartitionRangeDatum typedef struct PartitionCmd { NodeTag type; - RangeVar *name; /* name of partition to attach/detach */ + RangeVar *name; /* name of partition to attach/detach/merge */ PartitionBoundSpec *bound; /* FOR VALUES, if attaching */ + List *partlist; /* list of partitions, for MERGE + * PARTITION command */ bool concurrent; } PartitionCmd; @@ -2473,6 +2475,7 @@ typedef enum AlterTableType AT_AttachPartition, /* ATTACH PARTITION */ AT_DetachPartition, /* DETACH PARTITION */ AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */ + AT_MergePartitions, /* MERGE PARTITIONS */ AT_AddIdentity, /* ADD IDENTITY */ AT_SetIdentity, /* SET identity column options */ AT_DropIdentity, /* DROP IDENTITY */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index a4af3f717a..90e8cddf8b 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -337,6 +337,7 @@ PG_KEYWORD("parameter", PARAMETER, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("parser", PARSER, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("partitions", PARTITIONS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL) diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h index 65f161f718..690d259619 100644 --- a/src/include/partitioning/partbounds.h +++ b/src/include/partitioning/partbounds.h @@ -143,4 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc, extern int partition_hash_bsearch(PartitionBoundInfo boundinfo, int modulus, int remainder); +extern void calculate_partition_bound_for_merge(Relation parent, + List *partNames, + List *partOids, + PartitionBoundSpec *spec, + ParseState *pstate); + #endif /* PARTBOUNDS_H */ diff --git a/src/test/isolation/expected/partition-merge.out b/src/test/isolation/expected/partition-merge.out new file mode 100644 index 0000000000..98446aaab5 --- /dev/null +++ b/src/test/isolation/expected/partition-merge.out @@ -0,0 +1,199 @@ +Parsed test spec with 2 sessions + +starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule index e3c669a29c..0dca684955 100644 --- a/src/test/isolation/isolation_schedule +++ b/src/test/isolation/isolation_schedule @@ -107,6 +107,7 @@ test: partition-key-update-1 test: partition-key-update-2 test: partition-key-update-3 test: partition-key-update-4 +test: partition-merge test: plpgsql-toast test: cluster-conflict test: cluster-conflict-partition diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec new file mode 100644 index 0000000000..dc2b9d3445 --- /dev/null +++ b/src/test/isolation/specs/partition-merge.spec @@ -0,0 +1,54 @@ +# Verify that MERGE operation locks DML operations with partitioned table + +setup +{ + DROP TABLE IF EXISTS tpart; + CREATE TABLE tpart(i int, t text) partition by range(i); + CREATE TABLE tpart_00_10 PARTITION OF tpart FOR VALUES FROM (0) TO (10); + CREATE TABLE tpart_10_20 PARTITION OF tpart FOR VALUES FROM (10) TO (20); + CREATE TABLE tpart_20_30 PARTITION OF tpart FOR VALUES FROM (20) TO (30); + CREATE TABLE tpart_default PARTITION OF tpart DEFAULT; + INSERT INTO tpart VALUES (5, 'text05'); + INSERT INTO tpart VALUES (15, 'text15'); + INSERT INTO tpart VALUES (25, 'text25'); + INSERT INTO tpart VALUES (35, 'text35'); +} + +teardown +{ + DROP TABLE tpart; +} + +session s1 +step s1b { BEGIN; } +step s1brr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s1bs { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s1merg { ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; } +step s1c { COMMIT; } + + +session s2 +step s2b { BEGIN; } +step s2brr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s2bs { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s2i { INSERT INTO tpart VALUES (1, 'text01'); } +step s2u { UPDATE tpart SET t = 'text01modif' where i = 1; } +step s2c { COMMIT; } +step s2s { SELECT * FROM tpart; } + + +# s2 inserts row into table. s1 starts MERGE PARTITIONS then +# s2 is trying to update inserted row and waits until s1 finishes +# MERGE operation. + +permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2b s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2b s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +permutation s2brr s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2brr s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2brr s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +permutation s2bs s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2bs s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2bs s2i s2c s1bs s1merg s2b s2u s1c s2c s2s diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c index 193669f2bc..7de5ddb878 100644 --- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c +++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c @@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS) case AT_DetachPartitionFinalize: strtype = "DETACH PARTITION ... FINALIZE"; break; + case AT_MergePartitions: + strtype = "MERGE PARTITIONS"; + break; case AT_AddIdentity: strtype = "ADD IDENTITY"; break; diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out new file mode 100644 index 0000000000..1cd34fae2d --- /dev/null +++ b/src/test/regress/expected/partition_merge.out @@ -0,0 +1,1234 @@ +-- +-- PARTITIONS_MERGE +-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command +-- +CREATE SCHEMA partitions_merge_schema; +CREATE SCHEMA partitions_merge_schema2; +SET search_path = partitions_merge_schema, public; +-- +-- BY RANGE partitioning +-- +-- +-- Test for error codes +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_dec2021 PARTITION OF sales_range FOR VALUES FROM ('2021-12-01') TO ('2021-12-31'); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-15'); +CREATE TABLE sales_apr_2 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-15') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022; +ERROR: partition with name "sales_feb2022" is already used +LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2... + ^ +-- ERROR: "sales_apr2022" is not a table +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +ERROR: "sales_apr2022" is not a table +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022" +-- (space between sections sales_jan2022 and sales_mar2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022; +ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022" +HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent. +-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021" +-- (space between sections sales_dec2021 and sales_jan2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021" +HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent. +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022; +ERROR: partition with name "sales_feb2022" is already used +LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions... + ^ +-- NO ERROR: test for custom partitions order, source partitions not in the search_path +SET search_path = partitions_merge_schema2, public; +ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS ( + partitions_merge_schema.sales_feb2022, + partitions_merge_schema.sales_mar2022, + partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022; +SET search_path = partitions_merge_schema, public; +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +------------------------------------------------+---------+------------------+-------------------------------------------------- + partitions_merge_schema2.sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022') + sales_apr2022 | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_dec2021 | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021') + sales_others | r | f | DEFAULT +(4 rows) + +DROP TABLE sales_range; +-- +-- Add rows into partitioned table, then merge partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); +SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass); + pg_get_partkeydef +-------------------- + RANGE (sales_date) +(1 row) + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +---------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_feb2022 | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022') + sales_jan2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022') + sales_mar2022 | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022') + sales_others | r | f | DEFAULT +(5 rows) + +-- check schema-qualified name of the new partition +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022; +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +------------------------------------------------+---------+------------------+-------------------------------------------------- + partitions_merge_schema2.sales_feb_mar_apr2022 | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022') + sales_jan2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022') + sales_others | r | f | DEFAULT +(3 rows) + +SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2'; + schemaname | tablename | indexname | tablespace | indexdef +--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------ + partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date) +(1 row) + +SELECT * FROM sales_range; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 3 | Ford | 2000 | 04-30-2022 + 4 | Ivanov | 750 | 04-13-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 14 | Smith | 510 | 05-04-2022 +(14 rows) + +SELECT * FROM sales_jan2022; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 +(3 rows) + +SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 3 | Ford | 2000 | 04-30-2022 + 4 | Ivanov | 750 | 04-13-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 +(10 rows) + +SELECT * FROM sales_others; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 14 | Smith | 510 | 05-04-2022 +(1 row) + +-- Use indexscan for testing indexes +SET enable_seqscan = OFF; +SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 11 | Trump | 380 | 04-06-2022 + 5 | Deev | 250 | 04-07-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(10 rows) + +RESET enable_seqscan; +DROP TABLE sales_range; +-- +-- Merge some partitions into DEFAULT partition +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); +-- Merge partitions (include DEFAULT partition) into partition with the same +-- name +ALTER TABLE sales_range MERGE PARTITIONS + (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others; +select * from sales_others; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 14 | Smith | 510 | 05-04-2022 +(7 rows) + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +---------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_feb2022 | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022') + sales_others | r | f | DEFAULT +(3 rows) + +DROP TABLE sales_range; +-- +-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. +-- +CREATE TABLE sales_date (salesperson_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT, + sales_date VARCHAR(10) GENERATED ALWAYS AS + (LPAD(sales_year::text, 4, '0') || '.' || LPAD(sales_month::text, 2, '0') || '.' || LPAD(sales_day::text, 2, '0')) STORED, + sales_department VARCHAR(30) DEFAULT 'Sales department') + PARTITION BY RANGE (sales_year, sales_month, sales_day); +CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1); +CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1); +CREATE TABLE sales_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1); +CREATE TABLE sales_other PARTITION OF sales_date FOR VALUES FROM (2022, 3, 1) TO (MAXVALUE, MAXVALUE, MAXVALUE); +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2021, 12, 7), + ('Manager2', 2021, 12, 8), + ('Manager3', 2022, 1, 1), + ('Manager1', 2022, 2, 4), + ('Manager2', 2022, 1, 2), + ('Manager3', 2022, 2, 1), + ('Manager1', 2022, 3, 3), + ('Manager2', 2022, 3, 4), + ('Manager3', 2022, 5, 1); +SELECT * FROM sales_date; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(9 rows) + +SELECT * FROM sales_dec2022; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department +(2 rows) + +SELECT * FROM sales_jan2022; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department +(2 rows) + +SELECT * FROM sales_feb2022; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department +(2 rows) + +SELECT * FROM sales_other; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(3 rows) + +ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022; +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2022, 1, 10), + ('Manager2', 2022, 2, 10); +SELECT * FROM sales_date; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department + Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(11 rows) + +SELECT * FROM sales_dec2022; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department +(2 rows) + +SELECT * FROM sales_jan_feb2022; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department + Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department +(6 rows) + +SELECT * FROM sales_other; + salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +------------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(3 rows) + +DROP TABLE sales_date; +-- +-- Test: merge partitions of partitioned table with triggers +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20); +CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30); +CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40); +INSERT INTO salespeople VALUES (1, 'Poirot'); +CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN NULL; +END; +$BODY$; +CREATE TRIGGER salespeople_after_insert_statement_trigger + AFTER INSERT + ON salespeople + FOR EACH STATEMENT + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); +CREATE TRIGGER salespeople_after_insert_row_trigger + AFTER INSERT + ON salespeople + FOR EACH ROW + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (10, 'May'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_20 VALUES (19, 'Ivanov'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (20, 'Smirnoff'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_40 VALUES (30, 'Ford'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +SELECT * FROM salespeople01_10; + salesperson_id | salesperson_name +----------------+------------------ + 1 | Poirot +(1 row) + +SELECT * FROM salespeople10_40; + salesperson_id | salesperson_name +----------------+------------------ + 10 | May + 19 | Ivanov + 20 | Smirnoff + 30 | Ford +(4 rows) + +DROP TABLE salespeople; +DROP FUNCTION after_insert_row_trigger(); +-- +-- Test: merge partitions with deleted columns +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +-- Create partitions with some deleted columns: +CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30)); +INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov'); +INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff'); +INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov'); +ALTER TABLE salespeople10_20 DROP COLUMN d1; +ALTER TABLE salespeople20_30 DROP COLUMN d2; +ALTER TABLE salespeople30_40 DROP COLUMN d3; +ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20); +ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30); +ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40); +INSERT INTO salespeople VALUES + (1, 'Poirot'), + (10, 'May'), + (30, 'Ford'); +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; +select * from salespeople; + salesperson_id | salesperson_name +----------------+------------------ + 1 | Poirot + 19 | Ivanov + 10 | May + 20 | Smirnoff + 31 | Popov + 30 | Ford +(6 rows) + +select * from salespeople01_10; + salesperson_id | salesperson_name +----------------+------------------ + 1 | Poirot +(1 row) + +select * from salespeople10_40; + salesperson_id | salesperson_name +----------------+------------------ + 19 | Ivanov + 10 | May + 20 | Smirnoff + 31 | Popov + 30 | Ford +(5 rows) + +DROP TABLE salespeople; +-- +-- Test: merge sub-partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr2022_01_10 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'); +CREATE TABLE sales_apr2022_10_20 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'); +CREATE TABLE sales_apr2022_20_30 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); +SELECT * FROM sales_range; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 + 14 | Smith | 510 | 05-04-2022 +(14 rows) + +SELECT * FROM sales_apr2022; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +SELECT * FROM sales_apr2022_01_10; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 +(2 rows) + +SELECT * FROM sales_apr2022_10_20; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 4 | Ivanov | 750 | 04-13-2022 +(1 row) + +SELECT * FROM sales_apr2022_20_30; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 3 | Ford | 2000 | 04-30-2022 +(1 row) + +ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all; +SELECT * FROM sales_range; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 + 14 | Smith | 510 | 05-04-2022 +(14 rows) + +SELECT * FROM sales_apr2022; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +SELECT * FROM sales_apr_all; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +DROP TABLE sales_range; +-- +-- BY LIST partitioning +-- +-- +-- Test: specific errors for BY LIST partitioning +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; +CREATE TABLE sales_list2 (LIKE sales_list) PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT; +CREATE TABLE sales_external (LIKE sales_list); +CREATE TABLE sales_external2 (vch VARCHAR(5)); +-- ERROR: "sales_external" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all; +ERROR: "sales_external" is not a partition of partitioned table "sales_list" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all; +ERROR: "sales_external2" is not a partition of partitioned table "sales_list" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_nord2, sales_east) INTO sales_all; +ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +DROP TABLE sales_external2; +DROP TABLE sales_external; +DROP TABLE sales_list2; +DROP TABLE sales_list; +-- +-- Test: BY LIST partitioning, MERGE PARTITIONS with data +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_name); +CREATE INDEX sales_list_sales_state_idx ON sales_list USING btree (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; +INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES + ('Trump', 'Bejing', 1000, '2022-03-01'), + ('Smirnoff', 'New York', 500, '2022-03-03'), + ('Ford', 'St. Petersburg', 2000, '2022-03-05'), + ('Ivanov', 'Warsaw', 750, '2022-03-04'), + ('Deev', 'Lisbon', 250, '2022-03-07'), + ('Poirot', 'Berlin', 1000, '2022-03-01'), + ('May', 'Helsinki', 1200, '2022-03-06'), + ('Li', 'Vladivostok', 1150, '2022-03-09'), + ('May', 'Helsinki', 1200, '2022-03-11'), + ('Halder', 'Oslo', 800, '2022-03-02'), + ('Muller', 'Madrid', 650, '2022-03-05'), + ('Smith', 'Kyiv', 350, '2022-03-10'), + ('Gandi', 'Warsaw', 150, '2022-03-08'), + ('Plato', 'Lisbon', 950, '2022-03-05'); +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +---------------+---------+------------------+------------------------------------------------------ + sales_central | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv') + sales_east | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok') + sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki') + sales_west | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid') + sales_others | r | f | DEFAULT +(5 rows) + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all; +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +--------------+---------+------------------+-------------------------------------------------------------------------------------------------------------- + sales_all | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv') + sales_nord | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki') + sales_others | r | f | DEFAULT +(3 rows) + +SELECT * FROM sales_list; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+----------------+--------------+------------ + 2 | Smirnoff | New York | 500 | 03-03-2022 + 5 | Deev | Lisbon | 250 | 03-07-2022 + 11 | Muller | Madrid | 650 | 03-05-2022 + 14 | Plato | Lisbon | 950 | 03-05-2022 + 1 | Trump | Bejing | 1000 | 03-01-2022 + 8 | Li | Vladivostok | 1150 | 03-09-2022 + 4 | Ivanov | Warsaw | 750 | 03-04-2022 + 6 | Poirot | Berlin | 1000 | 03-01-2022 + 12 | Smith | Kyiv | 350 | 03-10-2022 + 13 | Gandi | Warsaw | 150 | 03-08-2022 + 3 | Ford | St. Petersburg | 2000 | 03-05-2022 + 7 | May | Helsinki | 1200 | 03-06-2022 + 9 | May | Helsinki | 1200 | 03-11-2022 + 10 | Halder | Oslo | 800 | 03-02-2022 +(14 rows) + +SELECT * FROM sales_nord; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+----------------+--------------+------------ + 3 | Ford | St. Petersburg | 2000 | 03-05-2022 + 7 | May | Helsinki | 1200 | 03-06-2022 + 9 | May | Helsinki | 1200 | 03-11-2022 + 10 | Halder | Oslo | 800 | 03-02-2022 +(4 rows) + +SELECT * FROM sales_all; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 2 | Smirnoff | New York | 500 | 03-03-2022 + 5 | Deev | Lisbon | 250 | 03-07-2022 + 11 | Muller | Madrid | 650 | 03-05-2022 + 14 | Plato | Lisbon | 950 | 03-05-2022 + 1 | Trump | Bejing | 1000 | 03-01-2022 + 8 | Li | Vladivostok | 1150 | 03-09-2022 + 4 | Ivanov | Warsaw | 750 | 03-04-2022 + 6 | Poirot | Berlin | 1000 | 03-01-2022 + 12 | Smith | Kyiv | 350 | 03-10-2022 + 13 | Gandi | Warsaw | 150 | 03-08-2022 +(10 rows) + +-- Use indexscan for testing indexes after merging partitions +SET enable_seqscan = OFF; +SELECT * FROM sales_all WHERE sales_state = 'Warsaw'; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 4 | Ivanov | Warsaw | 750 | 03-04-2022 + 13 | Gandi | Warsaw | 150 | 03-08-2022 +(2 rows) + +SELECT * FROM sales_list WHERE sales_state = 'Warsaw'; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 4 | Ivanov | Warsaw | 750 | 03-04-2022 + 13 | Gandi | Warsaw | 150 | 03-08-2022 +(2 rows) + +SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov'; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 4 | Ivanov | Warsaw | 750 | 03-04-2022 +(1 row) + +RESET enable_seqscan; +DROP TABLE sales_list; +-- +-- Try to MERGE partitions of another table. +-- +CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b); +CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2); +CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t); +CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C'); +CREATE TABLE t3 (i int, t text); +-- ERROR: relation "t1p1" is not a partition of relation "t2" +ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p; +ERROR: relation "t1p1" is not a partition of relation "t2" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: "t3" is not a partition of partitioned table "t2" +ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p; +ERROR: "t3" is not a partition of partitioned table "t2" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +DROP TABLE t3; +DROP TABLE t2; +DROP TABLE t1; +-- +-- Try to MERGE partitions of temporary table. +-- +CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i); +CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | pg_get_expr | relpersistence +--------+----------------------------+---------------- + tp_0_1 | FOR VALUES FROM (0) TO (1) | t + tp_1_2 | FOR VALUES FROM (1) TO (2) | t +(2 rows) + +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Partition should be temporary. +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | pg_get_expr | relpersistence +--------+----------------------------+---------------- + tp_0_2 | FOR VALUES FROM (0) TO (2) | t +(1 row) + +DROP TABLE t; +-- +-- Check the partition index name if the partition name is the same as one +-- of the merged partitions. +-- +CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +CREATE INDEX tidx ON t(i); +ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2; +-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'. +-- Not-null constraint name should be 'tp_1_2_i_not_null'. +\d+ tp_1_2 + Table "partitions_merge_schema.tp_1_2" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + i | integer | | not null | | plain | | +Partition of: t FOR VALUES FROM (0) TO (2) +Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2)) +Indexes: + "tp_1_2_pkey" PRIMARY KEY, btree (i) + "tp_1_2_i_idx" btree (i) +Not-null constraints: + "t_i_not_null" NOT NULL "i" (inherited) + +DROP TABLE t; +-- +-- Try mixing permanent and temporary partitions. +-- +SET search_path = partitions_merge_schema, pg_temp, public; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; + oid | relpersistence +-----+---------------- + t | p +(1 row) + +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | pg_get_expr | relpersistence +--------+----------------------------+---------------- + tp_0_1 | FOR VALUES FROM (0) TO (1) | p + tp_1_2 | FOR VALUES FROM (1) TO (2) | p +(2 rows) + +SET search_path = pg_temp, partitions_merge_schema, public; +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: cannot create a temporary relation as partition of permanent relation "t" +SET search_path = partitions_merge_schema, public; +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; +ERROR: cannot create a temporary relation as partition of permanent relation "t" +DROP TABLE t; +SET search_path = pg_temp, partitions_merge_schema, public; +BEGIN; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; + oid | relpersistence +-----+---------------- + t | t +(1 row) + +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | pg_get_expr | relpersistence +--------+----------------------------+---------------- + tp_0_1 | FOR VALUES FROM (0) TO (1) | t + tp_1_2 | FOR VALUES FROM (1) TO (2) | t +(2 rows) + +SET search_path = partitions_merge_schema, pg_temp, public; +-- Can't merge temporary partitions into a persistent partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ROLLBACK; +-- Check the new partition inherits parent's tablespace +SET search_path = partitions_merge_schema, public; +CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) + PARTITION BY RANGE (i) TABLESPACE regress_tblspace; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT tablename, tablespace FROM pg_tables + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename, tablespace; + tablename | tablespace +-----------+------------------ + t | regress_tblspace + tp_0_2 | regress_tblspace +(2 rows) + +SELECT tablename, indexname, tablespace FROM pg_indexes + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename, indexname, tablespace; + tablename | indexname | tablespace +-----------+-------------+------------------ + t | t_pkey | regress_tblspace + tp_0_2 | tp_0_2_pkey | regress_tblspace +(2 rows) + +DROP TABLE t; +-- Check the new partition inherits parent's table access method +SET search_path = partitions_merge_schema, public; +CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler; +CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT c.relname, a.amname +FROM pg_class c JOIN pg_am a ON c.relam = a.oid +WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass) +ORDER BY c.relname; + relname | amname +---------+----------------------- + t | partitions_merge_heap + tp_0_2 | partitions_merge_heap +(2 rows) + +DROP TABLE t; +DROP ACCESS METHOD partitions_merge_heap; +-- Test permission checks. The user needs to own the parent table and all +-- the merging partitions to do the merge. +CREATE ROLE regress_partition_merge_alice; +CREATE ROLE regress_partition_merge_bob; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_alice; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: must be owner of table t +RESET SESSION AUTHORIZATION; +ALTER TABLE t OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: must be owner of table tp_0_1 +RESET SESSION AUTHORIZATION; +ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: must be owner of table tp_1_2 +RESET SESSION AUTHORIZATION; +ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; +DROP TABLE t; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob; +DROP ROLE regress_partition_merge_alice; +DROP ROLE regress_partition_merge_bob; +-- Test: we can't merge partitions with different owners +CREATE ROLE regress_partitions_merge_alice; +CREATE ROLE regress_partitions_merge_bob; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob; +SET SESSION AUTHORIZATION regress_partitions_merge_alice; +CREATE TABLE tp_0_1(i int); +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION regress_partitions_merge_bob; +CREATE TABLE tp_1_2(i int); +RESET SESSION AUTHORIZATION; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); +-- Owner is 'regress_partitions_merge_alice': +\dt tp_0_1 + List of tables + Schema | Name | Type | Owner +-------------------------+--------+-------+-------------------------------- + partitions_merge_schema | tp_0_1 | table | regress_partitions_merge_alice +(1 row) + +-- Owner is 'regress_partitions_merge_bob': +\dt tp_1_2 + List of tables + Schema | Name | Type | Owner +-------------------------+--------+-------+------------------------------ + partitions_merge_schema | tp_1_2 | table | regress_partitions_merge_bob +(1 row) + +-- ERROR: partitions being merged have different owners +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: partitions being merged have different owners +DROP TABLE t; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob; +DROP ROLE regress_partitions_merge_alice; +DROP ROLE regress_partitions_merge_bob; +-- Test for hash partitioned table +CREATE TABLE t (i int) PARTITION BY HASH(i); +CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0); +CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1); +-- ERROR: partition of hash-partitioned table cannot be merged +ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3; +ERROR: partition of hash-partitioned table cannot be merged +-- ERROR: list of new partitions should contain at least two items +ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3; +ERROR: list of new partitions should contain at least two items +DROP TABLE t; +-- Test for merged partition properties: +-- * STATISTICS is empty +-- * COMMENT is empty +-- * DEFAULTS are the same as DEFAULTS for partitioned table +-- * STORAGE is the same as STORAGE for partitioned table +-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table +-- * TRIGGERS are the same as TRIGGERS for partitioned table +CREATE TABLE t +(i int NOT NULL, + t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t', + b bigint, + d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i)); +COMMENT ON COLUMN t.i IS 't1.i'; +CREATE TABLE tp_0_1 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_0_1', + b bigint, + d date GENERATED ALWAYS as ('2022-02-02') STORED); +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i'; +CREATE TABLE tp_1_2 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_1_2', + b bigint, + d date GENERATED ALWAYS as ('2022-03-03') STORED); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); +COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i'; +CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t; +CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1; +CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2; +ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0); +ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED; +ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID; +ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID; +INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1); +INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2); +CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS +$BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN new; +END; +$BODY$; +CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW + EXECUTE PROCEDURE trigger_function('t'); +CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_0_1'); +CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_1_2'); +\d+ tp_0_1 + Table "partitions_merge_schema.tp_0_1" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+-------------------------------------------------+---------+--------------+------------- + i | integer | | not null | | plain | | tp_0_1.i + t | text | | | 'default_tp_0_1'::text | main | | + b | bigint | | not null | | plain | | + d | date | | | generated always as ('02-02-2022'::date) stored | plain | | +Partition of: t FOR VALUES FROM (0) TO (1) +Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1)) +Check constraints: + "t_b_check" CHECK (b > 0) + "t_b_check1" CHECK (b > 0) NOT ENFORCED + "t_b_check2" CHECK (b > 0) NOT VALID +Statistics objects: + "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1 +Not-null constraints: + "tp_0_1_i_not_null" NOT NULL "i" (inherited) + "t_b_nn" NOT NULL "b" (inherited) NOT VALID +Triggers: + t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t + tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1') + +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1; +\d+ tp_0_1 + Table "partitions_merge_schema.tp_0_1" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+-------------------------------------------------+----------+--------------+------------- + i | integer | | not null | | plain | | + t | text | | | 'default_t'::text | extended | | + b | bigint | | not null | | plain | | + d | date | | | generated always as ('01-01-2022'::date) stored | plain | | +Partition of: t FOR VALUES FROM (0) TO (2) +Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2)) +Check constraints: + "t_b_check" CHECK (b > 0) + "t_b_check1" CHECK (b > 0) NOT ENFORCED + "t_b_check2" CHECK (b > 0) NOT VALID +Not-null constraints: + "t_i_not_null" NOT NULL "i" (inherited) + "t_b_nn" NOT NULL "b" (inherited) NOT VALID +Triggers: + t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t + +INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3); +NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW +SELECT tableoid::regclass, * FROM t ORDER BY b; + tableoid | i | t | b | d +----------+---+----------------+---+------------ + tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022 + tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022 + tp_0_1 | 1 | default_t | 3 | 01-01-2022 +(3 rows) + +DROP TABLE t; +DROP FUNCTION trigger_function(); +-- Test MERGE PARTITIONS with not valid foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Should be NOT VALID FOREIGN KEY +\d tp_0_2 + Table "partitions_merge_schema.tp_0_2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + i | integer | | not null | +Partition of: t FOR VALUES FROM (0) TO (2) +Indexes: + "tp_0_2_pkey" PRIMARY KEY, btree (i) +Referenced by: + TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID + +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey; +ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +DETAIL: Key (i)=(2) is not present in table "t". +DROP TABLE t_fk; +DROP TABLE t; +-- Test MERGE PARTITIONS with not enforced foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Should be NOT ENFORCED FOREIGN KEY +\d tp_0_2 + Table "partitions_merge_schema.tp_0_2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + i | integer | | not null | +Partition of: t FOR VALUES FROM (0) TO (2) +Indexes: + "tp_0_2_pkey" PRIMARY KEY, btree (i) +Referenced by: + TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED + +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED; +ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +DETAIL: Key (i)=(2) is not present in table "t". +DROP TABLE t_fk; +DROP TABLE t; +-- Test for recomputation of stored generated columns. +CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789); +INSERT INTO t VALUES (0), (1); +-- Should be 0 because partition identifier for row with i=0 is different from +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + count +------- + 0 +(1 row) + +-- "tab_id" column (stored generated column) with "tableoid" attribute requires +-- recomputation here. +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Should be 1 because partition identifier for row with i=0 is the same as +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + count +------- + 1 +(1 row) + +DROP TABLE t; +-- Test for generated columns (different order of columns in partitioned table +-- and partitions). +CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i); +CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10); +ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20); +ALTER TABLE t ADD CHECK (g > 0); +ALTER TABLE t ADD CHECK (i > 0); +INSERT INTO t VALUES (5), (15); +ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12; +INSERT INTO t VALUES (16); +-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check" +INSERT INTO t VALUES (0); +ERROR: new row for relation "tp_12" violates check constraint "t_i_check" +DETAIL: Failing row contains (0, virtual). +-- Should be 3 rows: (5), (15), (16): +SELECT i FROM t ORDER BY i; + i +---- + 5 + 15 + 16 +(3 rows) + +-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10: +SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5); + count +------- + 1 +(1 row) + +DROP TABLE t; +RESET search_path; +-- +DROP SCHEMA partitions_merge_schema; +DROP SCHEMA partitions_merge_schema2; diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index a424be2a6b..6464a238ac 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -123,7 +123,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr # The stats test resets stats, so nothing else needing stats access can be in # this group. # ---------- -test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa +test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate numa # event_trigger depends on create_am and cannot run concurrently with # any test that runs DDL diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql new file mode 100644 index 0000000000..5baba56392 --- /dev/null +++ b/src/test/regress/sql/partition_merge.sql @@ -0,0 +1,816 @@ +-- +-- PARTITIONS_MERGE +-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command +-- + +CREATE SCHEMA partitions_merge_schema; +CREATE SCHEMA partitions_merge_schema2; +SET search_path = partitions_merge_schema, public; + +-- +-- BY RANGE partitioning +-- + +-- +-- Test for error codes +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_dec2021 PARTITION OF sales_range FOR VALUES FROM ('2021-12-01') TO ('2021-12-31'); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); + +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-15'); +CREATE TABLE sales_apr_2 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-15') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); + +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; + +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022; +-- ERROR: "sales_apr2022" is not a table +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +-- ERROR: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022" +-- (space between sections sales_jan2022 and sales_mar2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022; +-- ERROR: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021" +-- (space between sections sales_dec2021 and sales_jan2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022; + +-- NO ERROR: test for custom partitions order, source partitions not in the search_path +SET search_path = partitions_merge_schema2, public; +ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS ( + partitions_merge_schema.sales_feb2022, + partitions_merge_schema.sales_mar2022, + partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022; +SET search_path = partitions_merge_schema, public; + +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +DROP TABLE sales_range; + +-- +-- Add rows into partitioned table, then merge partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); + +SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass); + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +-- check schema-qualified name of the new partition +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022; + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2'; + +SELECT * FROM sales_range; +SELECT * FROM sales_jan2022; +SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022; +SELECT * FROM sales_others; + +-- Use indexscan for testing indexes +SET enable_seqscan = OFF; + +SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + +RESET enable_seqscan; + +DROP TABLE sales_range; + +-- +-- Merge some partitions into DEFAULT partition +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); + +-- Merge partitions (include DEFAULT partition) into partition with the same +-- name +ALTER TABLE sales_range MERGE PARTITIONS + (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others; + +select * from sales_others; + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +DROP TABLE sales_range; + +-- +-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. +-- +CREATE TABLE sales_date (salesperson_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT, + sales_date VARCHAR(10) GENERATED ALWAYS AS + (LPAD(sales_year::text, 4, '0') || '.' || LPAD(sales_month::text, 2, '0') || '.' || LPAD(sales_day::text, 2, '0')) STORED, + sales_department VARCHAR(30) DEFAULT 'Sales department') + PARTITION BY RANGE (sales_year, sales_month, sales_day); + +CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1); +CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1); +CREATE TABLE sales_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1); +CREATE TABLE sales_other PARTITION OF sales_date FOR VALUES FROM (2022, 3, 1) TO (MAXVALUE, MAXVALUE, MAXVALUE); + +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2021, 12, 7), + ('Manager2', 2021, 12, 8), + ('Manager3', 2022, 1, 1), + ('Manager1', 2022, 2, 4), + ('Manager2', 2022, 1, 2), + ('Manager3', 2022, 2, 1), + ('Manager1', 2022, 3, 3), + ('Manager2', 2022, 3, 4), + ('Manager3', 2022, 5, 1); + +SELECT * FROM sales_date; +SELECT * FROM sales_dec2022; +SELECT * FROM sales_jan2022; +SELECT * FROM sales_feb2022; +SELECT * FROM sales_other; + +ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022; + +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2022, 1, 10), + ('Manager2', 2022, 2, 10); + +SELECT * FROM sales_date; +SELECT * FROM sales_dec2022; +SELECT * FROM sales_jan_feb2022; +SELECT * FROM sales_other; + +DROP TABLE sales_date; + +-- +-- Test: merge partitions of partitioned table with triggers +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); + +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20); +CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30); +CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40); + +INSERT INTO salespeople VALUES (1, 'Poirot'); + +CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN NULL; +END; +$BODY$; + +CREATE TRIGGER salespeople_after_insert_statement_trigger + AFTER INSERT + ON salespeople + FOR EACH STATEMENT + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); + +CREATE TRIGGER salespeople_after_insert_row_trigger + AFTER INSERT + ON salespeople + FOR EACH ROW + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); + +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (10, 'May'); +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_20 VALUES (19, 'Ivanov'); + +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; + +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (20, 'Smirnoff'); +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_40 VALUES (30, 'Ford'); + +SELECT * FROM salespeople01_10; +SELECT * FROM salespeople10_40; + +DROP TABLE salespeople; +DROP FUNCTION after_insert_row_trigger(); + +-- +-- Test: merge partitions with deleted columns +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); + +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +-- Create partitions with some deleted columns: +CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30)); + +INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov'); +INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff'); +INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov'); + +ALTER TABLE salespeople10_20 DROP COLUMN d1; +ALTER TABLE salespeople20_30 DROP COLUMN d2; +ALTER TABLE salespeople30_40 DROP COLUMN d3; + +ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20); +ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30); +ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40); + +INSERT INTO salespeople VALUES + (1, 'Poirot'), + (10, 'May'), + (30, 'Ford'); + +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; + +select * from salespeople; +select * from salespeople01_10; +select * from salespeople10_40; + +DROP TABLE salespeople; + +-- +-- Test: merge sub-partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); + +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr2022_01_10 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'); +CREATE TABLE sales_apr2022_10_20 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'); +CREATE TABLE sales_apr2022_20_30 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); + +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; + +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); + +SELECT * FROM sales_range; +SELECT * FROM sales_apr2022; +SELECT * FROM sales_apr2022_01_10; +SELECT * FROM sales_apr2022_10_20; +SELECT * FROM sales_apr2022_20_30; + +ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all; + +SELECT * FROM sales_range; +SELECT * FROM sales_apr2022; +SELECT * FROM sales_apr_all; + +DROP TABLE sales_range; + +-- +-- BY LIST partitioning +-- + +-- +-- Test: specific errors for BY LIST partitioning +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; + + +CREATE TABLE sales_list2 (LIKE sales_list) PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT; + + +CREATE TABLE sales_external (LIKE sales_list); +CREATE TABLE sales_external2 (vch VARCHAR(5)); + +-- ERROR: "sales_external" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all; +-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all; +-- ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_nord2, sales_east) INTO sales_all; + +DROP TABLE sales_external2; +DROP TABLE sales_external; +DROP TABLE sales_list2; +DROP TABLE sales_list; + +-- +-- Test: BY LIST partitioning, MERGE PARTITIONS with data +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); + +CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_name); +CREATE INDEX sales_list_sales_state_idx ON sales_list USING btree (sales_state); + +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; + +INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES + ('Trump', 'Bejing', 1000, '2022-03-01'), + ('Smirnoff', 'New York', 500, '2022-03-03'), + ('Ford', 'St. Petersburg', 2000, '2022-03-05'), + ('Ivanov', 'Warsaw', 750, '2022-03-04'), + ('Deev', 'Lisbon', 250, '2022-03-07'), + ('Poirot', 'Berlin', 1000, '2022-03-01'), + ('May', 'Helsinki', 1200, '2022-03-06'), + ('Li', 'Vladivostok', 1150, '2022-03-09'), + ('May', 'Helsinki', 1200, '2022-03-11'), + ('Halder', 'Oslo', 800, '2022-03-02'), + ('Muller', 'Madrid', 650, '2022-03-05'), + ('Smith', 'Kyiv', 350, '2022-03-10'), + ('Gandi', 'Warsaw', 150, '2022-03-08'), + ('Plato', 'Lisbon', 950, '2022-03-05'); + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all; + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +SELECT * FROM sales_list; +SELECT * FROM sales_nord; +SELECT * FROM sales_all; + +-- Use indexscan for testing indexes after merging partitions +SET enable_seqscan = OFF; + +SELECT * FROM sales_all WHERE sales_state = 'Warsaw'; +SELECT * FROM sales_list WHERE sales_state = 'Warsaw'; +SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov'; + +RESET enable_seqscan; + +DROP TABLE sales_list; + +-- +-- Try to MERGE partitions of another table. +-- +CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b); +CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2); +CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t); +CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C'); +CREATE TABLE t3 (i int, t text); + +-- ERROR: relation "t1p1" is not a partition of relation "t2" +ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p; +-- ERROR: "t3" is not a partition of partitioned table "t2" +ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p; + +DROP TABLE t3; +DROP TABLE t2; +DROP TABLE t1; + +-- +-- Try to MERGE partitions of temporary table. +-- +CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i); +CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Partition should be temporary. +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +DROP TABLE t; + +-- +-- Check the partition index name if the partition name is the same as one +-- of the merged partitions. +-- +CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i); + +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +CREATE INDEX tidx ON t(i); +ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2; + +-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'. +-- Not-null constraint name should be 'tp_1_2_i_not_null'. +\d+ tp_1_2 + +DROP TABLE t; + +-- +-- Try mixing permanent and temporary partitions. +-- +SET search_path = partitions_merge_schema, pg_temp, public; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +SET search_path = pg_temp, partitions_merge_schema, public; + +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +SET search_path = partitions_merge_schema, public; + +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; +DROP TABLE t; + +SET search_path = pg_temp, partitions_merge_schema, public; + +BEGIN; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; +SELECT c.oid::pg_catalog.regclass, pg_catalog.pg_get_expr(c.relpartbound, c.oid), c.relpersistence + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 't'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +SET search_path = partitions_merge_schema, pg_temp, public; + +-- Can't merge temporary partitions into a persistent partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ROLLBACK; + +-- Check the new partition inherits parent's tablespace +SET search_path = partitions_merge_schema, public; +CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) + PARTITION BY RANGE (i) TABLESPACE regress_tblspace; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT tablename, tablespace FROM pg_tables + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename, tablespace; +SELECT tablename, indexname, tablespace FROM pg_indexes + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename, indexname, tablespace; +DROP TABLE t; + +-- Check the new partition inherits parent's table access method +SET search_path = partitions_merge_schema, public; +CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler; +CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT c.relname, a.amname +FROM pg_class c JOIN pg_am a ON c.relam = a.oid +WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass) +ORDER BY c.relname; +DROP TABLE t; +DROP ACCESS METHOD partitions_merge_heap; + +-- Test permission checks. The user needs to own the parent table and all +-- the merging partitions to do the merge. +CREATE ROLE regress_partition_merge_alice; +CREATE ROLE regress_partition_merge_bob; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob; + +SET SESSION AUTHORIZATION regress_partition_merge_alice; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +ALTER TABLE t OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +DROP TABLE t; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob; +DROP ROLE regress_partition_merge_alice; +DROP ROLE regress_partition_merge_bob; + + +-- Test: we can't merge partitions with different owners +CREATE ROLE regress_partitions_merge_alice; +CREATE ROLE regress_partitions_merge_bob; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_alice; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partitions_merge_bob; +SET SESSION AUTHORIZATION regress_partitions_merge_alice; +CREATE TABLE tp_0_1(i int); +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION regress_partitions_merge_bob; +CREATE TABLE tp_1_2(i int); +RESET SESSION AUTHORIZATION; + +CREATE TABLE t (i int) PARTITION BY RANGE (i); + +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); + +-- Owner is 'regress_partitions_merge_alice': +\dt tp_0_1 +-- Owner is 'regress_partitions_merge_bob': +\dt tp_1_2 + +-- ERROR: partitions being merged have different owners +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +DROP TABLE t; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_alice; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partitions_merge_bob; +DROP ROLE regress_partitions_merge_alice; +DROP ROLE regress_partitions_merge_bob; + + +-- Test for hash partitioned table +CREATE TABLE t (i int) PARTITION BY HASH(i); +CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0); +CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1); + +-- ERROR: partition of hash-partitioned table cannot be merged +ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3; + +-- ERROR: list of new partitions should contain at least two items +ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3; + +DROP TABLE t; + + +-- Test for merged partition properties: +-- * STATISTICS is empty +-- * COMMENT is empty +-- * DEFAULTS are the same as DEFAULTS for partitioned table +-- * STORAGE is the same as STORAGE for partitioned table +-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table +-- * TRIGGERS are the same as TRIGGERS for partitioned table + +CREATE TABLE t +(i int NOT NULL, + t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t', + b bigint, + d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i)); +COMMENT ON COLUMN t.i IS 't1.i'; + +CREATE TABLE tp_0_1 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_0_1', + b bigint, + d date GENERATED ALWAYS as ('2022-02-02') STORED); +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i'; + +CREATE TABLE tp_1_2 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_1_2', + b bigint, + d date GENERATED ALWAYS as ('2022-03-03') STORED); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); +COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i'; + +CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t; +CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1; +CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2; + +ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0); +ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED; +ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID; +ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID; + +INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1); +INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2); +CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS +$BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN new; +END; +$BODY$; + +CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW + EXECUTE PROCEDURE trigger_function('t'); +CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_0_1'); +CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_1_2'); + +\d+ tp_0_1 +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1; +\d+ tp_0_1 + +INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3); +SELECT tableoid::regclass, * FROM t ORDER BY b; +DROP TABLE t; +DROP FUNCTION trigger_function(); + + +-- Test MERGE PARTITIONS with not valid foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Should be NOT VALID FOREIGN KEY +\d tp_0_2 +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey; + +DROP TABLE t_fk; +DROP TABLE t; + +-- Test MERGE PARTITIONS with not enforced foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); + +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Should be NOT ENFORCED FOREIGN KEY +\d tp_0_2 +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED; + +DROP TABLE t_fk; +DROP TABLE t; + + +-- Test for recomputation of stored generated columns. +CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789); +INSERT INTO t VALUES (0), (1); + +-- Should be 0 because partition identifier for row with i=0 is different from +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + +-- "tab_id" column (stored generated column) with "tableoid" attribute requires +-- recomputation here. +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Should be 1 because partition identifier for row with i=0 is the same as +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + +DROP TABLE t; + + +-- Test for generated columns (different order of columns in partitioned table +-- and partitions). +CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i); +CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10); +ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20); +ALTER TABLE t ADD CHECK (g > 0); +ALTER TABLE t ADD CHECK (i > 0); +INSERT INTO t VALUES (5), (15); + +ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12; + +INSERT INTO t VALUES (16); +-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check" +INSERT INTO t VALUES (0); +-- Should be 3 rows: (5), (15), (16): +SELECT i FROM t ORDER BY i; +-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10: +SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5); + +DROP TABLE t; + + +RESET search_path; + +-- +DROP SCHEMA partitions_merge_schema; +DROP SCHEMA partitions_merge_schema2; -- 2.40.1.windows.1