diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 09ad8400fd0..7b90789f87c 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -4743,6 +4743,25 @@ ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate); ALTER INDEX measurement_city_id_logdate_key ATTACH PARTITION measurement_y2006m02_city_id_logdate_key; ... + + + + + 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 9d23ad5a0fb..5cda1c94adb 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -37,6 +37,8 @@ ALTER TABLE [ IF EXISTS ] 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: @@ -1157,18 +1159,117 @@ 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. + Only simple, non-partitioned partitions can be merged. + The new partition (partition_name) + can have the same name as one of the merged partitions + (partition_name1, + partition_name2 [, ...]). + + + + If the DEFAULT partition is not in the + list of merged partitions: + + + + For range-partitioned tables, the ranges of merged partitions + must be adjacent in order to be merged. + The partition bounds of merged partitions are combined to form the new partition bound for + partition_name. + + + + + For list-partitioned tables, the partition bounds of + merged partitions are combined to form the new partition bound for + partition_name. + + + + If the DEFAULT partition is in the list of merged partitions: + + + + The partition partition_name + will be the new DEFAULT partition of the target table. + + + + + The partition bound specifications for merged partitions can be arbitrary. + + + + + + All merged partitions must have the same owner. + The owner of merged partitions will be the owner of the new partition. + It is the user's responsibility to setup ACL on + the new partition. + + + + ALTER TABLE MERGE PARTITION uses the partitioned + table itself as the template to construct the new partition. + The new partition will inherit the same table access method, persistence + type, and tablespace as the partitioned table. + + Constraints, column defaults, column generation expressions, identity + columns, indexes, and triggers are copied from the partitioned table to + the new partition. But extended statistics, security policies, etc, + won't be copied from the partitioned table. + Indexes and identity columns copied from the partitioned table will be + created afterward, once the data has been moved into the new partition. + + + + When partitions are merged, any objects depending on this partition, + such as constraints, triggers, extended statistics, etc, will be + dropped. + Eventually, we will drop all the merged partitions + (using RESTRICT mode) too; therefore, if any objects + are still dependent on them, + ALTER TABLE MERGE PARTITION would fail. + (see ). + + + + + Merging partitions acquires an 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). + + + + + ALTER TABLE MERGE PARTITIONS creates a new partition and + moves data from all merging partitions into it, which can take a long time. + So it is not recommended to use the command to merge very big partitions + with small ones. + + + + + 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 - tables, since only one pass over the table need be made. + tables, since only one pass over the table needs to be made. @@ -1407,7 +1508,18 @@ 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. + + + + + + partition_name1 + partition_name2 + + + The names of the tables being merged into the new partition. @@ -1840,6 +1952,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 838ed26d6b9..7489bbd5fb3 100644 --- a/src/backend/catalog/dependency.c +++ b/src/backend/catalog/dependency.c @@ -321,13 +321,63 @@ performDeletion(const ObjectAddress *object, } /* - * performMultipleDeletions: Similar to performDeletion, but act on multiple + * performDeletionCheck: Check whether a specific object can be safely deleted. + * This function does not perform any deletion; instead, it raises an error + * if the object cannot be deleted due to existing dependencies. + * + * It can be useful when you need to delete some objects later. See comments + * in performDeletion too. + * The behavior must be specified as DROP_RESTRICT. + */ +void +performDeletionCheck(const ObjectAddress *object, + DropBehavior behavior, int flags) +{ + Relation depRel; + ObjectAddresses *targetObjects; + + Assert(behavior == DROP_RESTRICT); + + depRel = table_open(DependRelationId, RowExclusiveLock); + + AcquireDeletionLock(object, 0); + + /* + * Construct a list of objects we want to delete later (ie, the given + * object plus everything directly or indirectly dependent on it). + */ + targetObjects = new_object_addresses(); + + findDependentObjects(object, + DEPFLAG_ORIGINAL, + flags, + NULL, /* empty stack */ + targetObjects, + NULL, /* no pendingObjects */ + &depRel); + + /* + * Check if deletion is allowed. + */ + reportDependentObjects(targetObjects, + behavior, + flags, + object); + + /* And clean up */ + free_object_addresses(targetObjects); + + table_close(depRel, RowExclusiveLock); +} + +/* + * performMultipleDeletions: Similar to performDeletion, but acts on multiple * objects at once. * * The main difference from issuing multiple performDeletion calls is that the * list of objects that would be implicitly dropped, for each object to be * dropped, is the union of the implicit-object list for all objects. This - * makes each check be more relaxed. + * makes each check more relaxed. */ void performMultipleDeletions(const ObjectAddresses *objects, diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c index 43b4507d86e..672b188930f 100644 --- a/src/backend/catalog/pg_constraint.c +++ b/src/backend/catalog/pg_constraint.c @@ -875,7 +875,7 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh) false))); constr->is_enforced = true; constr->skip_validation = !conForm->convalidated; - constr->initially_valid = true; + constr->initially_valid = conForm->convalidated; constr->is_no_inherit = conForm->connoinherit; notnulls = lappend(notnulls, constr); } diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 1c9ef53be20..f703293dbc3 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -740,6 +740,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition); static char GetAttributeCompression(Oid atttypid, const char *compression); static char GetAttributeStorage(Oid atttypid, const char *storagemode); +static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel, + PartitionCmd *cmd, AlterTableUtilityContext *context); /* ---------------------------------------------------------------- * DefineRelation @@ -4836,6 +4838,10 @@ AlterTableGetLockLevel(List *cmds) cmd_lockmode = ShareUpdateExclusiveLock; break; + case AT_MergePartitions: + cmd_lockmode = AccessExclusiveLock; + break; + default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -5271,6 +5277,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, /* No command-specific prep needed */ pass = AT_PASS_MISC; break; + case AT_MergePartitions: + ATSimplePermissions(cmd->subtype, rel, ATT_PARTITIONED_TABLE); + /* No command-specific prep needed */ + pass = AT_PASS_MISC; + break; default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -5667,6 +5678,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab, case AT_DetachPartitionFinalize: address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name); break; + case AT_MergePartitions: + cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode, + cur_pass, context); + Assert(cmd != NULL); + Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE); + ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def, + context); + break; default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -6707,6 +6726,8 @@ alter_table_type_to_string(AlterTableType cmdtype) return "DETACH PARTITION"; case AT_DetachPartitionFinalize: return "DETACH PARTITION ... FINALIZE"; + case AT_MergePartitions: + return "MERGE PARTITIONS"; case AT_AddIdentity: return "ALTER COLUMN ... ADD IDENTITY"; case AT_SetIdentity: @@ -20231,6 +20252,40 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel, } } +/* + * attachPartitionTable: attach a new partition to the partitioned table + * + * wqueue: the ALTER TABLE work queue; can be NULL when not running as part + * of an ALTER TABLE sequence. + * rel: partitioned relation; + * attachrel: relation of attached partition; + * bound: bounds of attached relation. + */ +static void +attachPartitionTable(List **wqueue, Relation rel, Relation attachrel, PartitionBoundSpec *bound) +{ + /* + * Create an inheritance; the relevant checks are performed inside the + * function. + */ + CreateInheritance(attachrel, rel, true); + + /* Update the pg_class entry. */ + StorePartitionBound(attachrel, rel, bound); + + /* Ensure there exists a correct set of indexes in the partition. */ + AttachPartitionEnsureIndexes(wqueue, rel, attachrel); + + /* and triggers */ + CloneRowTriggersToPartition(rel, attachrel); + + /* + * Clone foreign key constraints. Callee is responsible for setting up + * for phase 3 constraint verification. + */ + CloneForeignKeyConstraints(wqueue, rel, attachrel); +} + /* * ALTER TABLE ATTACH PARTITION FOR VALUES * @@ -20432,26 +20487,10 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd, check_new_partition_bound(RelationGetRelationName(attachrel), rel, cmd->bound, pstate); - /* OK to create inheritance. Rest of the checks performed there */ - CreateInheritance(attachrel, rel, true); - - /* Update the pg_class entry. */ - StorePartitionBound(attachrel, rel, cmd->bound); - - /* Ensure there exists a correct set of indexes in the partition. */ - AttachPartitionEnsureIndexes(wqueue, rel, attachrel); - - /* and triggers */ - CloneRowTriggersToPartition(rel, attachrel); + attachPartitionTable(wqueue, rel, attachrel, cmd->bound); /* - * Clone foreign key constraints. Callee is responsible for setting up - * for phase 3 constraint verification. - */ - CloneForeignKeyConstraints(wqueue, rel, attachrel); - - /* - * Generate partition constraint from the partition bound specification. + * Generate a partition constraint from the partition bound specification. * If the parent itself is a partition, make sure to include its * constraint as well. */ @@ -22047,3 +22086,822 @@ GetAttributeStorage(Oid atttypid, const char *storagemode) return cstorage; } + +/* + * buildExpressionExecutionStates: build the needed expression execution states + * for new partition (newPartRel) checks and initialize expressions for + * generated columns. All expressions should be created in "tab" + * (AlteredTableInfo structure). + */ +static void +buildExpressionExecutionStates(AlteredTableInfo *tab, Relation newPartRel, EState *estate) +{ + /* + * Build the needed expression execution states. Here, we expect only NOT + * NULL and CHECK constraint. + */ + foreach_ptr(NewConstraint, con, tab->constraints) + { + switch (con->contype) + { + case CONSTR_CHECK: + + /* + * We already expanded virtual expression in + * createTableConstraints. + */ + con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate); + break; + case CONSTR_NOTNULL: + /* Nothing to do here. */ + break; + default: + elog(ERROR, "unrecognized constraint type: %d", + (int) con->contype); + } + } + + /* Expression already planned in createTableConstraints */ + foreach_ptr(NewColumnValue, ex, tab->newvals) + ex->exprstate = ExecInitExpr((Expr *) ex->expr, NULL); +} + +/* + * evaluateGeneratedExpressionsAndCheckConstraints: evaluate any generated + * expressions for "tab" (AlteredTableInfo structure) whose inputs come from + * the new tuple (insertslot) of the new partition (newPartRel). + */ +static void +evaluateGeneratedExpressionsAndCheckConstraints(AlteredTableInfo *tab, + Relation newPartRel, + TupleTableSlot *insertslot, + ExprContext *econtext) +{ + econtext->ecxt_scantuple = insertslot; + + foreach_ptr(NewColumnValue, ex, tab->newvals) + { + if (!ex->is_generated) + continue; + + insertslot->tts_values[ex->attnum - 1] + = ExecEvalExpr(ex->exprstate, + econtext, + &insertslot->tts_isnull[ex->attnum - 1]); + } + + foreach_ptr(NewConstraint, con, tab->constraints) + { + switch (con->contype) + { + case CONSTR_CHECK: + if (!ExecCheck(con->qualstate, econtext)) + ereport(ERROR, + errcode(ERRCODE_CHECK_VIOLATION), + errmsg("check constraint \"%s\" of relation \"%s\" is violated by some row", + con->name, RelationGetRelationName(newPartRel)), + errtableconstraint(newPartRel, con->name)); + break; + case CONSTR_NOTNULL: + case CONSTR_FOREIGN: + /* Nothing to do here */ + break; + default: + elog(ERROR, "unrecognized constraint type: %d", + (int) con->contype); + } + } +} + +/* + * getAttributesList: build a list of columns (ColumnDef) based on parent_rel + */ +static List * +getAttributesList(Relation parent_rel) +{ + AttrNumber parent_attno; + TupleDesc modelDesc; + List *colList = NIL; + + modelDesc = RelationGetDescr(parent_rel); + + for (parent_attno = 1; parent_attno <= modelDesc->natts; + parent_attno++) + { + Form_pg_attribute attribute = TupleDescAttr(modelDesc, + parent_attno - 1); + ColumnDef *def; + + /* Ignore dropped columns in the parent. */ + if (attribute->attisdropped) + continue; + + def = makeColumnDef(NameStr(attribute->attname), attribute->atttypid, + attribute->atttypmod, attribute->attcollation); + + def->is_not_null = attribute->attnotnull; + + /* Copy identity. */ + def->identity = attribute->attidentity; + + /* Copy attgenerated. */ + def->generated = attribute->attgenerated; + + def->storage = attribute->attstorage; + + /* Likewise, copy compression. */ + if (CompressionMethodIsValid(attribute->attcompression)) + def->compression = + pstrdup(GetCompressionMethodName(attribute->attcompression)); + else + def->compression = NULL; + + /* Add to column list. */ + colList = lappend(colList, def); + } + + return colList; +} + +/* + * createTableConstraints: + * create check constraints, default values, and generated values for newRel + * based on parent_rel. tab is pending-work queue for newRel, we may need it in + * MergePartitionsMoveRows. + */ +static void +createTableConstraints(List **wqueue, AlteredTableInfo *tab, + Relation parent_rel, Relation newRel) +{ + TupleDesc tupleDesc; + TupleConstr *constr; + AttrMap *attmap; + AttrNumber parent_attno; + int ccnum; + List *constraints = NIL; + List *cookedConstraints = NIL; + + tupleDesc = RelationGetDescr(parent_rel); + constr = tupleDesc->constr; + + if (!constr) + return; + + /* + * Construct a map from the parent relation's attnos to the child rel's. + * This re-checks type match, etc, although it shouldn't be possible to + * have a failure since both tables are locked. + */ + attmap = build_attrmap_by_name(RelationGetDescr(newRel), + tupleDesc, + false); + + /* Cycle for default values. */ + for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++) + { + Form_pg_attribute attribute = TupleDescAttr(tupleDesc, + parent_attno - 1); + + /* Ignore dropped columns in the parent. */ + if (attribute->attisdropped) + continue; + + /* Copy the default, if present, and it should be copied. */ + if (attribute->atthasdef) + { + Node *this_default = NULL; + bool found_whole_row; + AttrNumber num; + Node *def; + NewColumnValue *newval; + + if (attribute->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL) + this_default = build_generation_expression(parent_rel, attribute->attnum); + else + { + this_default = TupleDescGetDefault(tupleDesc, attribute->attnum); + if (this_default == NULL) + elog(ERROR, "default expression not found for attribute %d of relation \"%s\"", + attribute->attnum, RelationGetRelationName(parent_rel)); + } + + num = attmap->attnums[parent_attno - 1]; + def = map_variable_attnos(this_default, 1, 0, attmap, InvalidOid, &found_whole_row); + + if (found_whole_row && attribute->attgenerated != '\0') + elog(ERROR, "cannot convert whole-row table reference"); + + /* Add a pre-cooked default expression. */ + StoreAttrDefault(newRel, num, def, true); + + /* + * Stored generated column expressions in parent_rel might + * reference the tableoid. newRel, parent_rel tableoid clear is + * not the same. If so, these stored generated columns require + * recomputation for newRel within MergePartitionsMoveRows. + */ + if (attribute->attgenerated == ATTRIBUTE_GENERATED_STORED) + { + newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue)); + newval->attnum = num; + newval->expr = expression_planner((Expr *) def); + newval->is_generated = (attribute->attgenerated != '\0'); + tab->newvals = lappend(tab->newvals, newval); + } + } + } + + /* Cycle for CHECK constraints. */ + for (ccnum = 0; ccnum < constr->num_check; ccnum++) + { + char *ccname = constr->check[ccnum].ccname; + char *ccbin = constr->check[ccnum].ccbin; + bool ccenforced = constr->check[ccnum].ccenforced; + bool ccnoinherit = constr->check[ccnum].ccnoinherit; + bool ccvalid = constr->check[ccnum].ccvalid; + Node *ccbin_node; + bool found_whole_row; + Constraint *constr; + + /* + * The partitioned table can not have a NO INHERIT check constraint + * (see StoreRelCheck function for details). + */ + Assert(!ccnoinherit); + + ccbin_node = map_variable_attnos(stringToNode(ccbin), + 1, 0, + attmap, + InvalidOid, &found_whole_row); + + /* + * For the moment we have to reject whole-row variables (as for CREATE + * TABLE LIKE and inheritances). + */ + if (found_whole_row) + elog(ERROR, "Constraint \"%s\" contains a whole-row reference to table \"%s\".", + ccname, + RelationGetRelationName(parent_rel)); + + constr = makeNode(Constraint); + constr->contype = CONSTR_CHECK; + constr->conname = pstrdup(ccname); + constr->deferrable = false; + constr->initdeferred = false; + constr->is_enforced = ccenforced; + constr->skip_validation = !ccvalid; + constr->initially_valid = ccvalid; + constr->is_no_inherit = ccnoinherit; + constr->raw_expr = NULL; + constr->cooked_expr = nodeToString(ccbin_node); + constr->location = -1; + constraints = lappend(constraints, constr); + } + + /* Install all CHECK constraints. */ + cookedConstraints = AddRelationNewConstraints(newRel, NIL, constraints, + false, true, true, NULL); + + /* Make the additional catalog changes visible. */ + CommandCounterIncrement(); + + /* + * parent_rel check constraint expression may reference tableoid, so later + * in MergePartitionsMoveRows, we need to evaluate the check constraint + * again for the newRel. We can check whether the check constraint + * contains a tableoid reference via pull_varattnos. + */ + foreach_ptr(CookedConstraint, ccon, cookedConstraints) + { + if (!ccon->skip_validation) + { + Node *qual; + Bitmapset *attnums = NULL; + + Assert(ccon->contype == CONSTR_CHECK); + qual = expand_generated_columns_in_expr(ccon->expr, newRel, 1); + pull_varattnos(qual, 1, &attnums); + + /* + * Add a check only if it contains a tableoid + * (TableOidAttributeNumber). + */ + if (bms_is_member(TableOidAttributeNumber - FirstLowInvalidHeapAttributeNumber, + attnums)) + { + NewConstraint *newcon; + + newcon = (NewConstraint *) palloc0(sizeof(NewConstraint)); + newcon->name = ccon->name; + newcon->contype = CONSTR_CHECK; + newcon->qual = qual; + + tab->constraints = lappend(tab->constraints, newcon); + } + } + } + + /* Don't need the cookedConstraints anymore. */ + list_free_deep(cookedConstraints); + + /* Reproduce not-null constraints. */ + if (constr->has_not_null) + { + List *nnconstraints; + + /* + * The "include_noinh" argument is false because a partitioned table + * can't have NO INHERIT constraint. + */ + nnconstraints = RelationGetNotNullConstraints(RelationGetRelid(parent_rel), + false, false); + + Assert(list_length(nnconstraints) > 0); + + /* + * We already set pg_attribute.attnotnull in createPartitionTable. No + * need call set_attnotnull again. + */ + AddRelationNewConstraints(newRel, NIL, nnconstraints, false, true, true, NULL); + } +} + +/* + * createPartitionTable: + * + * Create a new partition (newPartName) for the partitioned table (parent_rel). + * ownerId is determined by the partition on which the operation is performed, + * so it is passed separately. The new partition will inherit the access method + * and persistence type from the parent table. + * + * Returns the created relation (locked in AccessExclusiveLock mode). + */ +static Relation +createPartitionTable(List **wqueue, RangeVar *newPartName, + Relation parent_rel, Oid ownerId) +{ + Relation newRel; + Oid newRelId; + Oid existingRelid; + TupleDesc descriptor; + List *colList = NIL; + Oid relamId; + Oid namespaceId; + AlteredTableInfo *new_partrel_tab; + Form_pg_class parent_relform = parent_rel->rd_rel; + + /* If the existing rel is temp, it must belong to this session. */ + if (RELATION_IS_OTHER_TEMP(parent_rel)) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create as partition of temporary relation of another session")); + + /* Look up inheritance ancestors and generate the relation schema. */ + colList = getAttributesList(parent_rel); + + /* Create a tuple descriptor from the relation schema. */ + descriptor = BuildDescForRelation(colList); + + /* Look up the access method for the new relation. */ + relamId = (parent_relform->relam != InvalidOid) ? parent_relform->relam : HEAP_TABLE_AM_OID; + + /* Look up the namespace in which we are supposed to create the relation. */ + namespaceId = + RangeVarGetAndCheckCreationNamespace(newPartName, NoLock, &existingRelid); + if (OidIsValid(existingRelid)) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("relation \"%s\" already exists", newPartName->relname)); + + /* + * We intended to create the partition with the same persistence as the + * parent table, but we still need to recheck because that might be + * affected by the search_path. If the parent is permanent, so must be + * all of its partitions. + */ + if (parent_relform->relpersistence != RELPERSISTENCE_TEMP && + newPartName->relpersistence == RELPERSISTENCE_TEMP) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"", + RelationGetRelationName(parent_rel))); + + /* Permanent rels cannot be partitions belonging to a temporary parent. */ + if (newPartName->relpersistence != RELPERSISTENCE_TEMP && + parent_relform->relpersistence == RELPERSISTENCE_TEMP) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create a permanent relation as partition of temporary relation \"%s\"", + RelationGetRelationName(parent_rel))); + + /* Create the relation. */ + newRelId = heap_create_with_catalog(newPartName->relname, + namespaceId, + parent_relform->reltablespace, + InvalidOid, + InvalidOid, + InvalidOid, + ownerId, + relamId, + descriptor, + NIL, + RELKIND_RELATION, + newPartName->relpersistence, + false, + false, + ONCOMMIT_NOOP, + (Datum) 0, + true, + allowSystemTableMods, + true, + InvalidOid, + NULL); + + /* + * We must bump the command counter to make the newly-created relation + * tuple visible for opening. + */ + CommandCounterIncrement(); + + /* + * Open the new partition with no lock, because we already have an + * AccessExclusiveLock placed there after creation. + */ + newRel = table_open(newRelId, NoLock); + + /* Find or create a work queue entry for the newly created table. */ + new_partrel_tab = ATGetQueueEntry(wqueue, newRel); + + /* Create constraints, default values, and generated values. */ + createTableConstraints(wqueue, new_partrel_tab, parent_rel, newRel); + + /* + * Need to call CommandCounterIncrement, so a fresh relcache entry has + * newly installed constraint info. + */ + CommandCounterIncrement(); + + return newRel; +} + +/* + * MergePartitionsMoveRows: scan partitions to be merged (mergingPartitions) + * of the partitioned table and move rows into the new partition + * (newPartRel). We also verify check constraints against these rows. + */ +static void +MergePartitionsMoveRows(List **wqueue, List *mergingPartitions, Relation newPartRel) +{ + CommandId mycid; + EState *estate; + AlteredTableInfo *tab; + ListCell *ltab; + + /* The FSM is empty, so don't bother using it. */ + int ti_options = TABLE_INSERT_SKIP_FSM; + BulkInsertState bistate; /* state of bulk inserts for partition */ + TupleTableSlot *dstslot; + + /* Find the work queue entry for the new partition table: newPartRel. */ + tab = ATGetQueueEntry(wqueue, newPartRel); + + /* Generate the constraint and default execution states. */ + estate = CreateExecutorState(); + + buildExpressionExecutionStates(tab, newPartRel, estate); + + mycid = GetCurrentCommandId(true); + + /* Prepare a BulkInsertState for table_tuple_insert. */ + bistate = GetBulkInsertState(); + + /* Create the necessary tuple slot. */ + dstslot = table_slot_create(newPartRel, NULL); + + foreach_oid(merging_oid, mergingPartitions) + { + ExprContext *econtext; + TupleTableSlot *srcslot; + TupleConversionMap *tuple_map; + TableScanDesc scan; + MemoryContext oldCxt; + Snapshot snapshot; + Relation mergingPartition; + + econtext = GetPerTupleExprContext(estate); + + /* + * Partition is already locked in the transformPartitionCmdForMerge + * function. + */ + mergingPartition = table_open(merging_oid, NoLock); + + /* Create a source tuple slot for the partition being merged. */ + srcslot = table_slot_create(mergingPartition, NULL); + + /* + * Map computing for moving attributes of the merged partition to the + * new partition. + */ + tuple_map = convert_tuples_by_name(RelationGetDescr(mergingPartition), + RelationGetDescr(newPartRel)); + + /* Scan through the rows. */ + snapshot = RegisterSnapshot(GetLatestSnapshot()); + scan = table_beginscan(mergingPartition, snapshot, 0, NULL); + + /* + * Switch to per-tuple memory context and reset it for each tuple + * produced, so we don't leak memory. + */ + oldCxt = MemoryContextSwitchTo(GetPerTupleMemoryContext(estate)); + + while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot)) + { + TupleTableSlot *insertslot; + + CHECK_FOR_INTERRUPTS(); + + if (tuple_map) + { + /* Need to use a map to copy attributes. */ + insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot); + } + else + { + slot_getallattrs(srcslot); + + /* Copy attributes directly. */ + insertslot = dstslot; + + ExecClearTuple(insertslot); + + memcpy(insertslot->tts_values, srcslot->tts_values, + sizeof(Datum) * srcslot->tts_nvalid); + memcpy(insertslot->tts_isnull, srcslot->tts_isnull, + sizeof(bool) * srcslot->tts_nvalid); + + ExecStoreVirtualTuple(insertslot); + } + + /* + * Constraints and GENERATED expressions might reference the + * tableoid column, so fill tts_tableOid with the desired value. + * (We must do this each time, because it gets overwritten with + * newrel's OID during storing.) + */ + insertslot->tts_tableOid = RelationGetRelid(newPartRel); + + /* + * Now, evaluate any generated expressions whose inputs come from + * the new tuple. We assume these columns won't reference each + * other, so that there's no ordering dependency. + */ + evaluateGeneratedExpressionsAndCheckConstraints(tab, newPartRel, + insertslot, econtext); + + /* Write the tuple out to the new relation. */ + table_tuple_insert(newPartRel, insertslot, mycid, + ti_options, bistate); + + ResetExprContext(econtext); + } + + MemoryContextSwitchTo(oldCxt); + table_endscan(scan); + UnregisterSnapshot(snapshot); + + if (tuple_map) + free_conversion_map(tuple_map); + + ExecDropSingleTupleTableSlot(srcslot); + table_close(mergingPartition, NoLock); + } + + FreeExecutorState(estate); + ExecDropSingleTupleTableSlot(dstslot); + FreeBulkInsertState(bistate); + + table_finish_bulk_insert(newPartRel, ti_options); + + /* + * We don't need to process this newPartRel since we already processed it + * here, so delete the ALTER TABLE queue for it. + */ + foreach(ltab, *wqueue) + { + tab = (AlteredTableInfo *) lfirst(ltab); + if (tab->relid == RelationGetRelid(newPartRel)) + { + *wqueue = list_delete_cell(*wqueue, ltab); + break; + } + } +} + +/* + * detachPartitionTable: detach partition "child_rel" from partitioned table + * "parent_rel" with default partition identifier "defaultPartOid" + */ +static void +detachPartitionTable(Relation parent_rel, Relation child_rel, Oid defaultPartOid) +{ + /* Remove the pg_inherits row first. */ + RemoveInheritance(child_rel, parent_rel, false); + + /* + * Detaching the partition might involve TOAST table access, so ensure we + * have a valid snapshot. + */ + PushActiveSnapshot(GetTransactionSnapshot()); + + /* Do the final part of detaching. */ + DetachPartitionFinalize(parent_rel, child_rel, false, defaultPartOid); + + PopActiveSnapshot(); +} + +/* + * ALTER TABLE 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 the next merging partition into the list. */ + mergingPartitions = lappend_oid(mergingPartitions, + RelationGetRelid(mergingPartition)); + + table_close(mergingPartition, NoLock); + } + + /* Look up the existing relation by the new partition name. */ + RangeVarGetAndCheckCreationNamespace(cmd->name, NoLock, &existingRelid); + + /* + * Check if this name is already taken. This helps us to detect the + * situation when one of the merging partitions has the same name as the + * new partition. Otherwise, this would fail later on anyway, but + * catching this here allows us to emit a nicer error message. + */ + if (OidIsValid(existingRelid)) + { + if (list_member_oid(mergingPartitions, existingRelid)) + { + /* + * The new partition has the same name as one of the merging + * partitions. + */ + char tmpRelName[NAMEDATALEN]; + + /* Generate a temporary name. */ + sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid); + + /* + * Rename the existing partition with a temporary name, leaving it + * free for the new partition. We don't need to care about this + * in the future because we're going to eventually drop the + * existing partition anyway. + */ + RenameRelationInternal(existingRelid, tmpRelName, true, false); + + /* + * We must bump the command counter to make the new partition + * tuple visible for rename. + */ + CommandCounterIncrement(); + } + else + { + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("relation \"%s\" already exists", cmd->name->relname)); + } + } + + defaultPartOid = + get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true)); + + /* Detach all merging partitions. */ + foreach_oid(mergingPartitionOid, mergingPartitions) + { + Relation child_rel; + + child_rel = table_open(mergingPartitionOid, NoLock); + + detachPartitionTable(rel, child_rel, defaultPartOid); + + table_close(child_rel, NoLock); + } + + /* + * Perform a preliminary check to determine whether it's safe to drop all + * merging partitions before we actually do so later. After merging rows + * into the new partitions via MergePartitionsMoveRows, all old partitions + * need to be dropped. However, since the drop behavior is DROP_RESTRICT + * and the merge process (MergePartitionsMoveRows) can be time-consuming, + * performing an early check on the drop eligibility of old partitions is + * preferable. + */ + foreach_oid(mergingPartitionOid, mergingPartitions) + { + ObjectAddress object; + + /* Get oid of the later to be dropped relation. */ + object.objectId = mergingPartitionOid; + object.classId = RelationRelationId; + object.objectSubId = 0; + + performDeletionCheck(&object, DROP_RESTRICT, PERFORM_DELETION_INTERNAL); + } + + /* + * Create a table for the new partition, using the partitioned table as a + * model. + */ + Assert(OidIsValid(ownerId)); + newPartRel = createPartitionTable(wqueue, cmd->name, rel, ownerId); + + /* + * Switch to the table owner's userid, so that any index functions are run + * as that user. Also, lockdown security-restricted operations and + * arrange to make GUC variable changes local to this command. + * + * Need to do it after determining the namespace in the + * createPartitionTable() call. + */ + GetUserIdAndSecContext(&save_userid, &save_sec_context); + SetUserIdAndSecContext(ownerId, + save_sec_context | SECURITY_RESTRICTED_OPERATION); + save_nestlevel = NewGUCNestLevel(); + RestrictSearchPath(); + + /* Copy data from merged partitions to the new partition. */ + MergePartitionsMoveRows(wqueue, mergingPartitions, newPartRel); + + /* Drop the current partitions before attaching the new one. */ + foreach_oid(mergingPartitionOid, mergingPartitions) + { + ObjectAddress object; + + object.objectId = mergingPartitionOid; + object.classId = RelationRelationId; + object.objectSubId = 0; + + performDeletion(&object, DROP_RESTRICT, 0); + } + + list_free(mergingPartitions); + + /* + * Attach a new partition to the partitioned table. wqueue = NULL: + * verification for each cloned constraint is not needed. + */ + attachPartitionTable(NULL, rel, newPartRel, cmd->bound); + + /* Keep the lock until commit. */ + table_close(newPartRel, NoLock); + + /* Roll back any GUC changes executed by index functions. */ + AtEOXact_GUC(false, save_nestlevel); + + /* Restore the userid and security context. */ + SetUserIdAndSecContext(save_userid, save_sec_context); +} diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 7856ce9d78f..562f11d6677 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -762,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); ORDER ORDINALITY OTHERS OUT_P OUTER_P OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER - PARALLEL PARAMETER PARSER PARTIAL PARTITION PASSING PASSWORD PATH + PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PATH PERIOD PLACING PLAN PLANS POLICY POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION @@ -2395,6 +2395,7 @@ partition_cmd: n->subtype = AT_AttachPartition; cmd->name = $3; cmd->bound = $4; + cmd->partlist = NIL; cmd->concurrent = false; n->def = (Node *) cmd; @@ -2409,6 +2410,7 @@ partition_cmd: n->subtype = AT_DetachPartition; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NIL; cmd->concurrent = $4; n->def = (Node *) cmd; @@ -2422,6 +2424,21 @@ partition_cmd: n->subtype = AT_DetachPartitionFinalize; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NIL; + cmd->concurrent = false; + n->def = (Node *) cmd; + $$ = (Node *) n; + } + /* ALTER TABLE 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; @@ -2438,6 +2455,7 @@ index_partition_cmd: n->subtype = AT_AttachPartition; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NIL; cmd->concurrent = false; n->def = (Node *) cmd; @@ -18038,6 +18056,7 @@ unreserved_keyword: | PARSER | PARTIAL | PARTITION + | PARTITIONS | PASSING | PASSWORD | PATH @@ -18668,6 +18687,7 @@ bare_label_keyword: | PARSER | PARTIAL | PARTITION + | PARTITIONS | PASSING | PASSWORD | PATH diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c index e96b38a59d5..bf02e38785d 100644 --- a/src/backend/parser/parse_utilcmd.c +++ b/src/backend/parser/parse_utilcmd.c @@ -32,6 +32,7 @@ #include "catalog/heap.h" #include "catalog/index.h" #include "catalog/namespace.h" +#include "catalog/partition.h" #include "catalog/pg_am.h" #include "catalog/pg_collation.h" #include "catalog/pg_constraint.h" @@ -58,6 +59,8 @@ #include "parser/parse_type.h" #include "parser/parse_utilcmd.h" #include "parser/parser.h" +#include "partitioning/partbounds.h" +#include "partitioning/partdesc.h" #include "rewrite/rewriteManip.h" #include "utils/acl.h" #include "utils/builtins.h" @@ -3509,6 +3512,135 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString, } +/* + * checkPartition + * Check whether partRelOid is a leaf partition of the parent table (rel). + */ +static void +checkPartition(Relation rel, Oid partRelOid) +{ + Relation partRel; + + partRel = table_open(partRelOid, NoLock); + + if (partRel->rd_rel->relkind != RELKIND_RELATION) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("\"%s\" is not a table", RelationGetRelationName(partRel)), + errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")); + + if (!partRel->rd_rel->relispartition) + ereport(ERROR, + errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("\"%s\" is not a partition of partitioned table \"%s\"", + RelationGetRelationName(partRel), RelationGetRelationName(rel)), + errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")); + + if (get_partition_parent(partRelOid, false) != RelationGetRelid(rel)) + ereport(ERROR, + errcode(ERRCODE_UNDEFINED_TABLE), + errmsg("relation \"%s\" is not a partition of relation \"%s\"", + RelationGetRelationName(partRel), RelationGetRelationName(rel)), + errhint("ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions")); + + table_close(partRel, NoLock); +} + +/* + * transformPartitionCmdForMerge - + * analyze the ALTER TABLE ... MERGE PARTITIONS command + * + * Does simple checks for merged partitions. Calculates bound of the resulting + * partition. + */ +static void +transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd) +{ + Oid defaultPartOid; + Oid partOid; + Relation parent = cxt->rel; + PartitionKey key; + char strategy; + ListCell *listptr, + *listptr2; + bool isDefaultPart = false; + List *partOids = NIL; + + key = RelationGetPartitionKey(parent); + strategy = get_partition_strategy(key); + + if (strategy == PARTITION_STRATEGY_HASH) + ereport(ERROR, + errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("partition of hash-partitioned table cannot be merged")); + + /* Does the partitioned table (parent) have a default partition? */ + defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent, true)); + + foreach(listptr, partcmd->partlist) + { + RangeVar *name = (RangeVar *) lfirst(listptr); + + /* Partitions in the list should have different names. */ + for_each_cell(listptr2, partcmd->partlist, lnext(partcmd->partlist, listptr)) + { + RangeVar *name2 = (RangeVar *) lfirst(listptr2); + + if (equal(name, name2)) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("partition with name \"%s\" is already used", name->relname), + parser_errposition(cxt->pstate, name2->location)); + } + + /* + * Search the DEFAULT partition in the list. Open and lock partitions + * before calculating the boundary for resulting partition, we also + * check for ownership along the way. We need to use + * AccessExclusiveLock here, because these merged partitions will be + * detached and then dropped in ATExecMergePartitions. + */ + partOid = RangeVarGetRelidExtended(name, AccessExclusiveLock, 0, + RangeVarCallbackOwnsRelation, + NULL); + /* Is the current partition a DEFAULT partition? */ + if (partOid == defaultPartOid) + isDefaultPart = true; + + /* + * Extended check because the same partition can have different names + * (for example, "part_name" and "public.part_name"). + */ + foreach(listptr2, partOids) + { + Oid curOid = lfirst_oid(listptr2); + + if (curOid == partOid) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("partition with name \"%s\" is already used", name->relname), + parser_errposition(cxt->pstate, name->location)); + } + + checkPartition(parent, partOid); + + partOids = lappend_oid(partOids, partOid); + } + + /* Allocate the bound of the resulting partition. */ + Assert(partcmd->bound == NULL); + partcmd->bound = makeNode(PartitionBoundSpec); + + /* Fill the partition bound. */ + partcmd->bound->strategy = strategy; + partcmd->bound->location = -1; + partcmd->bound->is_default = isDefaultPart; + if (!isDefaultPart) + calculate_partition_bound_for_merge(parent, partcmd->partlist, + partOids, partcmd->bound, + cxt->pstate); +} + /* * transformAlterTableStmt - * parse analysis for ALTER TABLE @@ -3786,12 +3918,26 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt, newcmds = lappend(newcmds, cmd); break; + case AT_MergePartitions: + { + PartitionCmd *partcmd = (PartitionCmd *) cmd->def; + + if (list_length(partcmd->partlist) < 2) + ereport(ERROR, + errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("list of partitions to be merged should include at least two partitions")); + + transformPartitionCmdForMerge(&cxt, partcmd); + newcmds = lappend(newcmds, cmd); + break; + } + default: /* - * Currently, we shouldn't actually get here for subcommand - * types that don't require transformation; but if we do, just - * emit them unchanged. + * Currently, we shouldn't actually get here for the + * subcommand types that don't require transformation; but if + * we do, just emit them unchanged. */ newcmds = lappend(newcmds, cmd); break; diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c index 40ac700d529..b82b29de8f7 100644 --- a/src/backend/partitioning/partbounds.c +++ b/src/backend/partitioning/partbounds.c @@ -4968,3 +4968,199 @@ satisfies_hash_partition(PG_FUNCTION_ARGS) PG_RETURN_BOOL(rowHash % modulus == remainder); } + +/* + * check_two_partitions_bounds_range + * + * (function for BY RANGE partitioning) + * + * This is a helper function for calculate_partition_bound_for_merge(). This + * function compares the upper bound of first_bound and the lower bound of + * second_bound. These bounds should be equal. + * + * parent: partitioned table + * first_name: name of the first partition + * first_bound: bound of the first partition + * second_name: name of the second partition + * second_bound: bound of the second partition + * pstate: pointer to ParseState struct for determining error position + */ +static void +check_two_partitions_bounds_range(Relation parent, + RangeVar *first_name, + PartitionBoundSpec *first_bound, + RangeVar *second_name, + PartitionBoundSpec *second_bound, + ParseState *pstate) +{ + PartitionKey key = RelationGetPartitionKey(parent); + PartitionRangeBound *first_upper; + PartitionRangeBound *second_lower; + int cmpval; + + Assert(key->strategy == PARTITION_STRATEGY_RANGE); + + first_upper = make_one_partition_rbound(key, -1, first_bound->upperdatums, false); + second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true); + + /* + * lower1 argument of partition_rbound_cmp() is set to false for the + * correct comparison result of the lower and upper bounds. + */ + cmpval = partition_rbound_cmp(key->partnatts, + key->partsupfunc, + key->partcollation, + second_lower->datums, second_lower->kind, + false, first_upper); + if (cmpval) + { + PartitionRangeDatum *datum = linitial(second_bound->lowerdatums); + + ereport(ERROR, + errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("can not merge partition \"%s\" together with partition \"%s\"", + second_name->relname, first_name->relname), + errdetail("lower bound of partition \"%s\" is not equal to the upper bound of partition \"%s\"", + second_name->relname, first_name->relname), + errhint("ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent."), + parser_errposition(pstate, datum->location)); + } +} + +/* + * get_partition_bound_spec + * + * Returns the PartitionBoundSpec for the partition with the given OID partOid. + */ +static PartitionBoundSpec * +get_partition_bound_spec(Oid partOid) +{ + HeapTuple tuple; + Datum datum; + bool isnull; + PartitionBoundSpec *boundspec = NULL; + + /* Try fetching the tuple from the catcache, for speed. */ + tuple = SearchSysCache1(RELOID, partOid); + if (!HeapTupleIsValid(tuple)) + elog(ERROR, "cache lookup failed for relation %u", partOid); + + datum = SysCacheGetAttr(RELOID, tuple, + Anum_pg_class_relpartbound, + &isnull); + if (isnull) + elog(ERROR, "partition bound for relation %u is null", + partOid); + + boundspec = stringToNode(TextDatumGetCString(datum)); + + if (!IsA(boundspec, PartitionBoundSpec)) + elog(ERROR, "expected PartitionBoundSpec for relation %u", + partOid); + + ReleaseSysCache(tuple); + return boundspec; +} + +/* + * calculate_partition_bound_for_merge + * + * Calculates the bound of the merged partition "spec" by using the bounds of + * the partitions to be merged. + * + * parent: partitioned table + * partNames: names of partitions to be merged + * partOids: Oids of partitions to be merged + * spec (out): bounds specification of the merged partition + * pstate: pointer to ParseState struct to determine error position + */ +void +calculate_partition_bound_for_merge(Relation parent, + List *partNames, + List *partOids, + PartitionBoundSpec *spec, + ParseState *pstate) +{ + PartitionKey key = RelationGetPartitionKey(parent); + PartitionBoundSpec *bound; + + Assert(!spec->is_default); + + switch (key->strategy) + { + case PARTITION_STRATEGY_RANGE: + { + int i; + PartitionRangeBound **lower_bounds; + int nparts = list_length(partOids); + List *bounds = NIL; + + lower_bounds = (PartitionRangeBound **) + palloc0(nparts * sizeof(PartitionRangeBound *)); + + /* + * Create an array of lower bounds and a list of + * PartitionBoundSpec. + */ + foreach_oid(partoid, partOids) + { + bound = get_partition_bound_spec(partoid); + i = foreach_current_index(partoid); + + lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true); + bounds = lappend(bounds, bound); + } + + /* Sort the array of lower bounds. */ + qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *), + qsort_partition_rbound_cmp, key); + + /* Ranges of partitions should be adjacent. */ + for (i = 1; i < nparts; i++) + { + int index = lower_bounds[i]->index; + int prev_index = lower_bounds[i - 1]->index; + + check_two_partitions_bounds_range(parent, + (RangeVar *) list_nth(partNames, prev_index), + (PartitionBoundSpec *) list_nth(bounds, prev_index), + (RangeVar *) list_nth(partNames, index), + (PartitionBoundSpec *) list_nth(bounds, index), + pstate); + } + + /* + * The lower bound of the first partition is the lower bound + * of the merged partition. + */ + spec->lowerdatums = + ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums; + + /* + * The upper bound of the last partition is the upper bound of + * the merged partition. + */ + spec->upperdatums = + ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[nparts - 1]->index))->upperdatums; + + pfree(lower_bounds); + list_free(bounds); + break; + } + + case PARTITION_STRATEGY_LIST: + { + /* Consolidate bounds for all partitions in the list. */ + foreach_oid(partoid, partOids) + { + bound = get_partition_bound_spec(partoid); + spec->listdatums = list_concat(spec->listdatums, bound->listdatums); + } + break; + } + + default: + elog(ERROR, "unexpected partition strategy: %d", + (int) key->strategy); + } +} diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c index 20d7a65c614..3176fd92ad3 100644 --- a/src/bin/psql/tab-complete.in.c +++ b/src/bin/psql/tab-complete.in.c @@ -2773,6 +2773,7 @@ match_previous_words(int pattern_id, "OWNER TO", "SET", "VALIDATE CONSTRAINT", "REPLICA IDENTITY", "ATTACH PARTITION", "DETACH PARTITION", "FORCE ROW LEVEL SECURITY", + "MERGE PARTITIONS (", "OF", "NOT OF"); /* ALTER TABLE xxx ADD */ else if (Matches("ALTER", "TABLE", MatchAny, "ADD")) @@ -3046,6 +3047,15 @@ match_previous_words(int pattern_id, else if (Matches("ALTER", "TABLE", MatchAny, "DETACH", "PARTITION", MatchAny)) COMPLETE_WITH("CONCURRENTLY", "FINALIZE"); + /* ALTER TABLE 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 06a8761e3fe..35cc35a0a71 100644 --- a/src/include/catalog/dependency.h +++ b/src/include/catalog/dependency.h @@ -107,6 +107,8 @@ extern void ReleaseDeletionLock(const ObjectAddress *object); extern void performDeletion(const ObjectAddress *object, DropBehavior behavior, int flags); +extern void performDeletionCheck(const ObjectAddress *object, + DropBehavior behavior, int flags); extern void performMultipleDeletions(const ObjectAddresses *objects, DropBehavior behavior, int flags); diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index d14294a4ece..e43a1f946a9 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -966,13 +966,16 @@ typedef struct PartitionRangeDatum } PartitionRangeDatum; /* - * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands + * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION and for + * ALTER TABLE MERGE PARTITIONS commands */ typedef struct PartitionCmd { NodeTag type; - RangeVar *name; /* name of partition to attach/detach */ + RangeVar *name; /* name of partition to attach/detach/merge */ PartitionBoundSpec *bound; /* FOR VALUES, if attaching */ + List *partlist; /* list of partitions to be merged, used in + * ALTER TABLE MERGE PARTITIONS */ bool concurrent; } PartitionCmd; @@ -2476,6 +2479,7 @@ typedef enum AlterTableType AT_AttachPartition, /* ATTACH PARTITION */ AT_DetachPartition, /* DETACH PARTITION */ AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */ + AT_MergePartitions, /* MERGE PARTITIONS */ AT_AddIdentity, /* ADD IDENTITY */ AT_SetIdentity, /* SET identity column options */ AT_DropIdentity, /* DROP IDENTITY */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 5d4fe27ef96..d4cda29c2a2 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -339,6 +339,7 @@ PG_KEYWORD("parameter", PARAMETER, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("parser", PARSER, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("partitions", PARTITIONS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL) diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h index cf93f9e5bef..25c311ff9bd 100644 --- a/src/include/partitioning/partbounds.h +++ b/src/include/partitioning/partbounds.h @@ -143,4 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc, extern int partition_hash_bsearch(PartitionBoundInfo boundinfo, int modulus, int remainder); +extern void calculate_partition_bound_for_merge(Relation parent, + List *partNames, + List *partOids, + PartitionBoundSpec *spec, + ParseState *pstate); + #endif /* PARTBOUNDS_H */ diff --git a/src/test/isolation/expected/partition-merge.out b/src/test/isolation/expected/partition-merge.out new file mode 100644 index 00000000000..5f6472671b9 --- /dev/null +++ b/src/test/isolation/expected/partition-merge.out @@ -0,0 +1,243 @@ +Parsed test spec with 2 sessions + +starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+----------- +tpart_00_20 | 1|text01modif +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u2: UPDATE tpart SET i = 21 where i = 1; +step s1c: COMMIT; +step s2u2: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+------ +tpart_00_20 | 5|text05 +tpart_00_20 |15|text15 +tpart_20_30 |21|text01 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u3: UPDATE tpart SET i = 11 where i = 1; +step s1c: COMMIT; +step s2u3: <... completed> +step s2c: COMMIT; +step s2s: SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; +tableoid | i|t +-------------+--+------ +tpart_00_20 | 5|text05 +tpart_00_20 |11|text01 +tpart_00_20 |15|text15 +tpart_20_30 |25|text25 +tpart_default|35|text35 +(5 rows) + diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule index 112f05a3677..db42c535ba6 100644 --- a/src/test/isolation/isolation_schedule +++ b/src/test/isolation/isolation_schedule @@ -109,6 +109,7 @@ test: partition-key-update-1 test: partition-key-update-2 test: partition-key-update-3 test: partition-key-update-4 +test: partition-merge test: plpgsql-toast test: cluster-conflict test: cluster-conflict-partition diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec new file mode 100644 index 00000000000..f3c5ce2fbf1 --- /dev/null +++ b/src/test/isolation/specs/partition-merge.spec @@ -0,0 +1,62 @@ +# Verify that MERGE operation locks DML operations with partitioned table + +setup +{ + DROP TABLE IF EXISTS tpart; + CREATE TABLE tpart(i int, t text) partition by range(i); + CREATE TABLE tpart_00_10 PARTITION OF tpart FOR VALUES FROM (0) TO (10); + CREATE TABLE tpart_10_20 PARTITION OF tpart FOR VALUES FROM (10) TO (20); + CREATE TABLE tpart_20_30 PARTITION OF tpart FOR VALUES FROM (20) TO (30); + CREATE TABLE tpart_default PARTITION OF tpart DEFAULT; + INSERT INTO tpart VALUES (5, 'text05'); + INSERT INTO tpart VALUES (15, 'text15'); + INSERT INTO tpart VALUES (25, 'text25'); + INSERT INTO tpart VALUES (35, 'text35'); +} + +teardown +{ + DROP TABLE tpart; +} + +session s1 +step s1b { BEGIN; } +step s1brr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s1bs { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s1merg { ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; } +step s1c { COMMIT; } + + +session s2 +step s2b { BEGIN; } +step s2brr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s2bs { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s2i { INSERT INTO tpart VALUES (1, 'text01'); } +step s2u { UPDATE tpart SET t = 'text01modif' where i = 1; } +step s2u2 { UPDATE tpart SET i = 21 where i = 1; } +step s2u3 { UPDATE tpart SET i = 11 where i = 1; } +step s2c { COMMIT; } +step s2s { SELECT tableoid::regclass, * FROM tpart ORDER BY tableoid::regclass::text COLLATE "C", i; } + + +# s2 inserts row into table. s1 starts MERGE PARTITIONS then +# s2 is trying to update inserted row and waits until s1 finishes +# MERGE operation. + +permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2b s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2b s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +permutation s2brr s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2brr s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2brr s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +permutation s2bs s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2bs s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2bs s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +# Tuple routing between partitions. +permutation s2b s2i s2c s1b s1merg s2b s2u2 s1c s2c s2s + +# Tuple routing between merging partitions. +permutation s2b s2i s2c s1b s1merg s2b s2u3 s1c s2c s2s diff --git a/src/test/modules/test_ddl_deparse/expected/alter_table.out b/src/test/modules/test_ddl_deparse/expected/alter_table.out index f1c6f05fe17..6b5b40905e7 100644 --- a/src/test/modules/test_ddl_deparse/expected/alter_table.out +++ b/src/test/modules/test_ddl_deparse/expected/alter_table.out @@ -113,6 +113,11 @@ ALTER TABLE part DETACH PARTITION part2; NOTICE: DDL test: type alter table, tag ALTER TABLE NOTICE: subcommand: type DETACH PARTITION desc table part2 DROP TABLE part2; +CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200); +NOTICE: DDL test: type simple, tag CREATE TABLE +ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1; +NOTICE: DDL test: type alter table, tag ALTER TABLE +NOTICE: subcommand: type MERGE PARTITIONS desc ALTER TABLE part ADD PRIMARY KEY (a); NOTICE: DDL test: type alter table, tag ALTER TABLE NOTICE: subcommand: type ADD CONSTRAINT (and recurse) desc constraint part_a_not_null on table part diff --git a/src/test/modules/test_ddl_deparse/sql/alter_table.sql b/src/test/modules/test_ddl_deparse/sql/alter_table.sql index 380ba266075..a0549ef8247 100644 --- a/src/test/modules/test_ddl_deparse/sql/alter_table.sql +++ b/src/test/modules/test_ddl_deparse/sql/alter_table.sql @@ -60,6 +60,9 @@ ALTER TABLE part ATTACH PARTITION part2 FOR VALUES FROM (101) to (200); ALTER TABLE part DETACH PARTITION part2; DROP TABLE part2; +CREATE TABLE part2 PARTITION OF part FOR VALUES FROM (100) to (200); +ALTER TABLE part MERGE PARTITIONS (part1, part2) INTO part1; + ALTER TABLE part ADD PRIMARY KEY (a); CREATE TABLE tbl ( diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c index 193669f2bc1..7de5ddb8785 100644 --- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c +++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c @@ -296,6 +296,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS) case AT_DetachPartitionFinalize: strtype = "DETACH PARTITION ... FINALIZE"; break; + case AT_MergePartitions: + strtype = "MERGE PARTITIONS"; + break; case AT_AddIdentity: strtype = "ADD IDENTITY"; break; diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out new file mode 100644 index 00000000000..3e40abf38a0 --- /dev/null +++ b/src/test/regress/expected/partition_merge.out @@ -0,0 +1,1097 @@ +-- +-- PARTITIONS_MERGE +-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command +-- +CREATE SCHEMA partitions_merge_schema; +CREATE SCHEMA partitions_merge_schema2; +SET search_path = partitions_merge_schema, public; +-- +-- BY RANGE partitioning +-- +-- +-- Test for error codes +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_dec2021 PARTITION OF sales_range FOR VALUES FROM ('2021-12-01') TO ('2021-12-31'); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-15'); +CREATE TABLE sales_apr_2 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-15') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022; +ERROR: partition with name "sales_feb2022" is already used +LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2... + ^ +-- ERROR: "sales_apr2022" is not a table +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +ERROR: "sales_apr2022" is not a table +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022" +-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022" +-- (space between sections sales_jan2022 and sales_mar2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022; +ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022" +DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022" +HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent. +-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021" +-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021" +-- (space between sections sales_dec2021 and sales_jan2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021" +DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021" +HINT: ALTER TABLE ... MERGE PARTITIONS requires the partition bounds to be adjacent. +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022; +ERROR: partition with name "sales_feb2022" is already used +LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions... + ^ +--ERROR, sales_apr_2 already exists +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2; +ERROR: relation "sales_apr_2" already exists +CREATE VIEW jan2022v as SELECT * FROM sales_jan2022; +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +ERROR: cannot drop table sales_jan2022 because other objects depend on it +DETAIL: view jan2022v depends on table sales_jan2022 +HINT: Use DROP ... CASCADE to drop the dependent objects too. +DROP VIEW jan2022v; +-- NO ERROR: test for custom partitions order, source partitions not in the search_path +SET search_path = partitions_merge_schema2, public; +ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS ( + partitions_merge_schema.sales_feb2022, + partitions_merge_schema.sales_mar2022, + partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022; +SET search_path = partitions_merge_schema, public; +PREPARE get_partition_info(regclass[]) AS +SELECT c.oid::pg_catalog.regclass, + c.relpersistence, + c.relkind, + i.inhdetachpending, + pg_catalog.pg_get_expr(c.relpartbound, c.oid) +FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i +WHERE c.oid = i.inhrelid AND i.inhparent = ANY($1) +ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', + c.oid::regclass::text COLLATE "C"; +EXECUTE get_partition_info('{sales_range}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +------------------------------------------------+----------------+---------+------------------+-------------------------------------------------- + partitions_merge_schema2.sales_jan_feb_mar2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022') + sales_apr2022 | p | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_dec2021 | p | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021') + sales_others | p | r | f | DEFAULT +(4 rows) + +DROP TABLE sales_range; +-- +-- Add rows into partitioned table, then merge partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); +SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass); + pg_get_partkeydef +-------------------- + RANGE (sales_date) +(1 row) + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_range}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +---------------+----------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022') + sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022') + sales_mar2022 | p | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022') + sales_others | p | r | f | DEFAULT +(5 rows) + +-- check schema-qualified name of the new partition +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022; +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_range}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +------------------------------------------------+----------------+---------+------------------+-------------------------------------------------- + partitions_merge_schema2.sales_feb_mar_apr2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022') + sales_jan2022 | p | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022') + sales_others | p | r | f | DEFAULT +(3 rows) + +SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2'; + schemaname | tablename | indexname | tablespace | indexdef +--------------------------+-----------------------+--------------------------------------+------------+------------------------------------------------------------------------------------------------------------------------------ + partitions_merge_schema2 | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema2.sales_feb_mar_apr2022 USING btree (sales_date) +(1 row) + +SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + tableoid | salesperson_id | salesperson_name | sales_amount | sales_date +------------------------------------------------+----------------+------------------+--------------+------------ + partitions_merge_schema2.sales_feb_mar_apr2022 | 2 | Smirnoff | 500 | 02-10-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 3 | Ford | 2000 | 04-30-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 4 | Ivanov | 750 | 04-13-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 5 | Deev | 250 | 04-07-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 6 | Poirot | 150 | 02-11-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 7 | Li | 175 | 03-08-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 8 | Ericsson | 185 | 02-23-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 9 | Muller | 250 | 03-11-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 11 | Trump | 380 | 04-06-2022 + partitions_merge_schema2.sales_feb_mar_apr2022 | 12 | Plato | 350 | 03-19-2022 + sales_jan2022 | 1 | May | 1000 | 01-31-2022 + sales_jan2022 | 10 | Halder | 350 | 01-28-2022 + sales_jan2022 | 13 | Gandi | 377 | 01-09-2022 + sales_others | 14 | Smith | 510 | 05-04-2022 +(14 rows) + +-- Use indexscan for testing indexes +SET enable_seqscan = OFF; +EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + QUERY PLAN +-------------------------------------------------------------------------------- + Index Scan using sales_feb_mar_apr2022_sales_date_idx on sales_feb_mar_apr2022 + Index Cond: (sales_date > '01-01-2022'::date) +(2 rows) + +SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 11 | Trump | 380 | 04-06-2022 + 5 | Deev | 250 | 04-07-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(10 rows) + +RESET enable_seqscan; +DROP TABLE sales_range; +-- +-- Merge some partitions into DEFAULT partition +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); +-- Merge partitions (include DEFAULT partition) into partition with the same +-- name +ALTER TABLE sales_range MERGE PARTITIONS + (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others; +SELECT * FROM sales_others ORDER BY salesperson_id; + salesperson_id | salesperson_name | sales_amount | sales_date +----------------+------------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 10 | Halder | 350 | 01-28-2022 + 12 | Plato | 350 | 03-19-2022 + 13 | Gandi | 377 | 01-09-2022 + 14 | Smith | 510 | 05-04-2022 +(7 rows) + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_range}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +---------------+----------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | p | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_feb2022 | p | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022') + sales_others | p | r | f | DEFAULT +(3 rows) + +DROP TABLE sales_range; +-- +-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. +-- +CREATE TABLE sales_date (salesperson_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT, + sales_date VARCHAR(10) GENERATED ALWAYS AS + (LPAD(sales_year::text, 4, '0') || '.' || LPAD(sales_month::text, 2, '0') || '.' || LPAD(sales_day::text, 2, '0')) STORED, + sales_department VARCHAR(30) DEFAULT 'Sales department') + PARTITION BY RANGE (sales_year, sales_month, sales_day); +CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1); +CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1); +CREATE TABLE sales_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1); +CREATE TABLE sales_other PARTITION OF sales_date FOR VALUES FROM (2022, 3, 1) TO (MAXVALUE, MAXVALUE, MAXVALUE); +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2021, 12, 7), + ('Manager2', 2021, 12, 8), + ('Manager3', 2022, 1, 1), + ('Manager1', 2022, 2, 4), + ('Manager2', 2022, 1, 2), + ('Manager3', 2022, 2, 1), + ('Manager1', 2022, 3, 3), + ('Manager2', 2022, 3, 4), + ('Manager3', 2022, 5, 1); +SELECT tableoid::regclass, * FROM sales_date; + tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------------+------------+-------------+-----------+------------+------------------ + sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department + sales_jan2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + sales_jan2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + sales_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + sales_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(9 rows) + +ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022; +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2022, 1, 10), + ('Manager2', 2022, 2, 10); +SELECT tableoid::regclass, * FROM sales_date; + tableoid | salesperson_name | sales_year | sales_month | sales_day | sales_date | sales_department +-------------------+------------------+------------+-------------+-----------+------------+------------------ + sales_dec2022 | Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + sales_dec2022 | Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department + sales_jan_feb2022 | Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + sales_jan_feb2022 | Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + sales_jan_feb2022 | Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + sales_jan_feb2022 | Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + sales_jan_feb2022 | Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department + sales_jan_feb2022 | Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department + sales_other | Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + sales_other | Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + sales_other | Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(11 rows) + +DROP TABLE sales_date; +-- +-- Test: merge partitions of partitioned table with triggers +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20); +CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30); +CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40); +INSERT INTO salespeople VALUES (1, 'Poirot'); +CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN NULL; +END; +$BODY$; +CREATE TRIGGER salespeople_after_insert_statement_trigger + AFTER INSERT + ON salespeople + FOR EACH STATEMENT + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); +CREATE TRIGGER salespeople_after_insert_row_trigger + AFTER INSERT + ON salespeople + FOR EACH ROW + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (10, 'May'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_20 VALUES (19, 'Ivanov'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (20, 'Smirnoff'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = STATEMENT +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_40 VALUES (30, 'Ford'); +NOTICE: trigger(salespeople) called: action = INSERT, when = AFTER, level = ROW +SELECT * FROM salespeople01_10; + salesperson_id | salesperson_name +----------------+------------------ + 1 | Poirot +(1 row) + +SELECT * FROM salespeople10_40; + salesperson_id | salesperson_name +----------------+------------------ + 10 | May + 19 | Ivanov + 20 | Smirnoff + 30 | Ford +(4 rows) + +DROP TABLE salespeople; +DROP FUNCTION after_insert_row_trigger(); +-- +-- Test: merge partitions with deleted columns +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +-- Create partitions with some deleted columns: +CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30)); +INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov'); +INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff'); +INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov'); +ALTER TABLE salespeople10_20 DROP COLUMN d1; +ALTER TABLE salespeople20_30 DROP COLUMN d2; +ALTER TABLE salespeople30_40 DROP COLUMN d3; +ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20); +ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30); +ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40); +INSERT INTO salespeople VALUES + (1, 'Poirot'), + (10, 'May'), + (30, 'Ford'); +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; +select * from salespeople; + salesperson_id | salesperson_name +----------------+------------------ + 1 | Poirot + 19 | Ivanov + 10 | May + 20 | Smirnoff + 31 | Popov + 30 | Ford +(6 rows) + +select * from salespeople01_10; + salesperson_id | salesperson_name +----------------+------------------ + 1 | Poirot +(1 row) + +select * from salespeople10_40; + salesperson_id | salesperson_name +----------------+------------------ + 19 | Ivanov + 10 | May + 20 | Smirnoff + 31 | Popov + 30 | Ford +(5 rows) + +DROP TABLE salespeople; +-- +-- Test: merge sub-partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr2022_01_10 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'); +CREATE TABLE sales_apr2022_10_20 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'); +CREATE TABLE sales_apr2022_20_30 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); +SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + tableoid | salesperson_id | salesperson_name | sales_amount | sales_date +---------------------+----------------+------------------+--------------+------------ + sales_apr2022_01_10 | 5 | Deev | 250 | 04-07-2022 + sales_apr2022_01_10 | 11 | Trump | 380 | 04-06-2022 + sales_apr2022_10_20 | 4 | Ivanov | 750 | 04-13-2022 + sales_apr2022_20_30 | 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all; +SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + tableoid | salesperson_id | salesperson_name | sales_amount | sales_date +---------------+----------------+------------------+--------------+------------ + sales_apr_all | 3 | Ford | 2000 | 04-30-2022 + sales_apr_all | 4 | Ivanov | 750 | 04-13-2022 + sales_apr_all | 5 | Deev | 250 | 04-07-2022 + sales_apr_all | 11 | Trump | 380 | 04-06-2022 +(4 rows) + +DROP TABLE sales_range; +-- +-- BY LIST partitioning +-- +-- +-- Test: specific errors for BY LIST partitioning +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; +CREATE TABLE sales_list2 (LIKE sales_list) PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT; +CREATE TABLE sales_external (LIKE sales_list); +CREATE TABLE sales_external2 (vch VARCHAR(5)); +-- ERROR: "sales_external" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all; +ERROR: "sales_external" is not a partition of partitioned table "sales_list" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all; +ERROR: "sales_external2" is not a partition of partitioned table "sales_list" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_nord2, sales_east) INTO sales_all; +ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +DROP TABLE sales_external2; +DROP TABLE sales_external; +DROP TABLE sales_list2; +DROP TABLE sales_list; +-- +-- Test: BY LIST partitioning, MERGE PARTITIONS with data +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_name); +CREATE INDEX sales_list_sales_state_idx ON sales_list USING btree (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; +INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES + ('Trump', 'Bejing', 1000, '2022-03-01'), + ('Smirnoff', 'New York', 500, '2022-03-03'), + ('Ford', 'St. Petersburg', 2000, '2022-03-05'), + ('Ivanov', 'Warsaw', 750, '2022-03-04'), + ('Deev', 'Lisbon', 250, '2022-03-07'), + ('Poirot', 'Berlin', 1000, '2022-03-01'), + ('May', 'Helsinki', 1200, '2022-03-06'), + ('Li', 'Vladivostok', 1150, '2022-03-09'), + ('May', 'Helsinki', 1200, '2022-03-11'), + ('Halder', 'Oslo', 800, '2022-03-02'), + ('Muller', 'Madrid', 650, '2022-03-05'), + ('Smith', 'Kyiv', 350, '2022-03-10'), + ('Gandi', 'Warsaw', 150, '2022-03-08'), + ('Plato', 'Lisbon', 950, '2022-03-05'); +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_list}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +---------------+----------------+---------+------------------+------------------------------------------------------ + sales_central | p | r | f | FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv') + sales_east | p | r | f | FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok') + sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki') + sales_west | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid') + sales_others | p | r | f | DEFAULT +(5 rows) + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all; +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_list}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +--------------+----------------+---------+------------------+-------------------------------------------------------------------------------------------------------------- + sales_all | p | r | f | FOR VALUES IN ('Lisbon', 'New York', 'Madrid', 'Bejing', 'Delhi', 'Vladivostok', 'Warsaw', 'Berlin', 'Kyiv') + sales_nord | p | r | f | FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki') + sales_others | p | r | f | DEFAULT +(3 rows) + +SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + tableoid | salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +------------+----------------+------------------+----------------+--------------+------------ + sales_all | 1 | Trump | Bejing | 1000 | 03-01-2022 + sales_all | 2 | Smirnoff | New York | 500 | 03-03-2022 + sales_all | 4 | Ivanov | Warsaw | 750 | 03-04-2022 + sales_all | 5 | Deev | Lisbon | 250 | 03-07-2022 + sales_all | 6 | Poirot | Berlin | 1000 | 03-01-2022 + sales_all | 8 | Li | Vladivostok | 1150 | 03-09-2022 + sales_all | 11 | Muller | Madrid | 650 | 03-05-2022 + sales_all | 12 | Smith | Kyiv | 350 | 03-10-2022 + sales_all | 13 | Gandi | Warsaw | 150 | 03-08-2022 + sales_all | 14 | Plato | Lisbon | 950 | 03-05-2022 + sales_nord | 3 | Ford | St. Petersburg | 2000 | 03-05-2022 + sales_nord | 7 | May | Helsinki | 1200 | 03-06-2022 + sales_nord | 9 | May | Helsinki | 1200 | 03-11-2022 + sales_nord | 10 | Halder | Oslo | 800 | 03-02-2022 +(14 rows) + +-- Use indexscan for testing indexes after merging partitions +SET enable_seqscan = OFF; +EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw'; + QUERY PLAN +--------------------------------------------------------- + Index Scan using sales_all_sales_state_idx on sales_all + Index Cond: ((sales_state)::text = 'Warsaw'::text) +(2 rows) + +SELECT * FROM sales_all WHERE sales_state = 'Warsaw'; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 4 | Ivanov | Warsaw | 750 | 03-04-2022 + 13 | Gandi | Warsaw | 150 | 03-08-2022 +(2 rows) + +EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw'; + QUERY PLAN +-------------------------------------------------------------------- + Index Scan using sales_all_sales_state_idx on sales_all sales_list + Index Cond: ((sales_state)::text = 'Warsaw'::text) +(2 rows) + +SELECT * FROM sales_list WHERE sales_state = 'Warsaw'; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 4 | Ivanov | Warsaw | 750 | 03-04-2022 + 13 | Gandi | Warsaw | 150 | 03-08-2022 +(2 rows) + +EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov'; + QUERY PLAN +--------------------------------------------------------------------------------- + Append + -> Index Scan using sales_all_salesperson_name_idx on sales_all sales_list_1 + Index Cond: ((salesperson_name)::text = 'Ivanov'::text) + -> Bitmap Heap Scan on sales_nord sales_list_2 + Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text) + -> Bitmap Index Scan on sales_nord_salesperson_name_idx + Index Cond: ((salesperson_name)::text = 'Ivanov'::text) + -> Bitmap Heap Scan on sales_others sales_list_3 + Recheck Cond: ((salesperson_name)::text = 'Ivanov'::text) + -> Bitmap Index Scan on sales_others_salesperson_name_idx + Index Cond: ((salesperson_name)::text = 'Ivanov'::text) +(11 rows) + +SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov'; + salesperson_id | salesperson_name | sales_state | sales_amount | sales_date +----------------+------------------+-------------+--------------+------------ + 4 | Ivanov | Warsaw | 750 | 03-04-2022 +(1 row) + +RESET enable_seqscan; +DROP TABLE sales_list; +-- +-- Try to MERGE partitions of another table. +-- +CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b); +CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2); +CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t); +CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C'); +CREATE TABLE t3 (i int, t text); +-- ERROR: relation "t1p1" is not a partition of relation "t2" +ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p; +ERROR: relation "t1p1" is not a partition of relation "t2" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +-- ERROR: "t3" is not a partition of partitioned table "t2" +ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p; +ERROR: "t3" is not a partition of partitioned table "t2" +HINT: ALTER TABLE ... MERGE PARTITIONS can only merge partitions don't have sub-partitions +DROP TABLE t3; +DROP TABLE t2; +DROP TABLE t1; +-- +-- Check the partition index name if the partition name is the same as one +-- of the merged partitions. +-- +CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +CREATE INDEX tidx ON t(i); +ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2; +-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'. +\d+ tp_1_2 + Table "partitions_merge_schema.tp_1_2" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + i | integer | | not null | | plain | | +Partition of: t FOR VALUES FROM (0) TO (2) +Partition constraint: ((i IS NOT NULL) AND (i >= 0) AND (i < 2)) +Indexes: + "tp_1_2_pkey" PRIMARY KEY, btree (i) + "tp_1_2_i_idx" btree (i) +Not-null constraints: + "t_i_not_null" NOT NULL "i" (inherited) + +DROP TABLE t; +-- +-- Try to MERGE partitions of temporary table. +-- +BEGIN; +SHOW search_path; + search_path +--------------------------------- + partitions_merge_schema, public +(1 row) + +CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP; +CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3); +CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; +ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3; +-- Partition should be temporary. +EXECUTE get_partition_info('{t}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +--------+----------------+---------+------------------+---------------------------- + tp_0_3 | t | r | f | FOR VALUES FROM (0) TO (3) + tp_3_4 | t | r | f | FOR VALUES FROM (3) TO (4) +(2 rows) + +-- ERROR: cannot create a permanent relation as partition of temporary relation "t" +ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4; +ERROR: cannot create a permanent relation as partition of temporary relation "t" +ROLLBACK; +-- +-- Try mixing permanent and temporary partitions. +-- +BEGIN; +SET search_path = partitions_merge_schema, pg_temp, public; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; + oid | relpersistence +-----+---------------- + t | p +(1 row) + +EXECUTE get_partition_info('{t}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +--------+----------------+---------+------------------+---------------------------- + tp_0_1 | p | r | f | FOR VALUES FROM (0) TO (1) + tp_1_2 | p | r | f | FOR VALUES FROM (1) TO (2) +(2 rows) + +SAVEPOINT s; +SET search_path = pg_temp, partitions_merge_schema, public; +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: cannot create a temporary relation as partition of permanent relation "t" +ROLLBACK TO SAVEPOINT s; +SET search_path = partitions_merge_schema, public; +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; +ERROR: cannot create a temporary relation as partition of permanent relation "t" +ROLLBACK; +BEGIN; +SET search_path = pg_temp, partitions_merge_schema, public; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; + oid | relpersistence +-----+---------------- + t | t +(1 row) + +EXECUTE get_partition_info('{t}'); + oid | relpersistence | relkind | inhdetachpending | pg_get_expr +--------+----------------+---------+------------------+---------------------------- + tp_0_1 | t | r | f | FOR VALUES FROM (0) TO (1) + tp_1_2 | t | r | f | FOR VALUES FROM (1) TO (2) +(2 rows) + +SET search_path = partitions_merge_schema, pg_temp, public; +-- Can't merge temporary partitions into a persistent partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: cannot create a permanent relation as partition of temporary relation "t" +ROLLBACK; +DEALLOCATE get_partition_info; +-- Check the new partition inherits parent's tablespace +SET search_path = partitions_merge_schema, public; +CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) + PARTITION BY RANGE (i) TABLESPACE regress_tblspace; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT tablename, tablespace FROM pg_tables + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename COLLATE "C", tablespace COLLATE "C"; + tablename | tablespace +-----------+------------------ + t | regress_tblspace + tp_0_2 | regress_tblspace +(2 rows) + +SELECT tablename, indexname, tablespace FROM pg_indexes + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C"; + tablename | indexname | tablespace +-----------+-------------+------------------ + t | t_pkey | regress_tblspace + tp_0_2 | tp_0_2_pkey | regress_tblspace +(2 rows) + +DROP TABLE t; +-- Check the new partition inherits parent's table access method +SET search_path = partitions_merge_schema, public; +CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler; +CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT c.relname, a.amname +FROM pg_class c JOIN pg_am a ON c.relam = a.oid +WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass) +ORDER BY c.relname COLLATE "C"; + relname | amname +---------+----------------------- + t | partitions_merge_heap + tp_0_2 | partitions_merge_heap +(2 rows) + +DROP TABLE t; +DROP ACCESS METHOD partitions_merge_heap; +-- Test permission checks. The user needs to own the parent table and all +-- the merging partitions to do the merge. +CREATE ROLE regress_partition_merge_alice; +CREATE ROLE regress_partition_merge_bob; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_alice; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- ERROR: must be owner of table t +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: must be owner of table t +RESET SESSION AUTHORIZATION; +ALTER TABLE t OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- ERROR: must be owner of table tp_0_1 +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: must be owner of table tp_0_1 +RESET SESSION AUTHORIZATION; +ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- ERROR: must be owner of table tp_1_2 +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: must be owner of table tp_1_2 +RESET SESSION AUTHORIZATION; +ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- Ok: +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; +DROP TABLE t; +-- Test: we can't merge partitions with different owners +CREATE TABLE tp_0_1(i int); +ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice; +CREATE TABLE tp_1_2(i int); +ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); +-- Owner is 'regress_partition_merge_alice': +\dt tp_0_1 + List of tables + Schema | Name | Type | Owner +-------------------------+--------+-------+------------------------------- + partitions_merge_schema | tp_0_1 | table | regress_partition_merge_alice +(1 row) + +-- Owner is 'regress_partition_merge_bob': +\dt tp_1_2 + List of tables + Schema | Name | Type | Owner +-------------------------+--------+-------+----------------------------- + partitions_merge_schema | tp_1_2 | table | regress_partition_merge_bob +(1 row) + +-- ERROR: partitions being merged have different owners +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ERROR: partitions being merged have different owners +DROP TABLE t; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob; +DROP ROLE regress_partition_merge_alice; +DROP ROLE regress_partition_merge_bob; +-- Test for hash partitioned table +CREATE TABLE t (i int) PARTITION BY HASH(i); +CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0); +CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1); +-- ERROR: partition of hash-partitioned table cannot be merged +ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3; +ERROR: partition of hash-partitioned table cannot be merged +-- ERROR: list of partitions to be merged should include at least two partitions +ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3; +ERROR: list of partitions to be merged should include at least two partitions +DROP TABLE t; +-- Test for merged partition properties: +-- * STATISTICS is empty +-- * COMMENT is empty +-- * DEFAULTS are the same as DEFAULTS for partitioned table +-- * STORAGE is the same as STORAGE for partitioned table +-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table +-- * TRIGGERS are the same as TRIGGERS for partitioned table +\set HIDE_TOAST_COMPRESSION false +CREATE TABLE t +(i int NOT NULL, + t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t', + b bigint, + d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i)); +COMMENT ON COLUMN t.i IS 't1.i'; +CREATE TABLE tp_0_1 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_0_1', + b bigint, + d date GENERATED ALWAYS as ('2022-02-02') STORED); +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i'; +CREATE TABLE tp_1_2 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_1_2', + b bigint, + d date GENERATED ALWAYS as ('2022-03-03') STORED); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); +COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i'; +CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t; +CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1; +CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2; +ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0); +ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED; +ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID; +ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID; +INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1); +INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2); +CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS +$BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN new; +END; +$BODY$; +CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW + EXECUTE PROCEDURE trigger_function('t'); +CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_0_1'); +CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_1_2'); +\d+ tp_0_1 + Table "partitions_merge_schema.tp_0_1" + Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description +--------+---------+-----------+----------+-------------------------------------------------+---------+-------------+--------------+------------- + i | integer | | not null | | plain | | | tp_0_1.i + t | text | | | 'default_tp_0_1'::text | main | | | + b | bigint | | not null | | plain | | | + d | date | | | generated always as ('02-02-2022'::date) stored | plain | | | +Partition of: t FOR VALUES FROM (0) TO (1) +Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 1)) +Check constraints: + "t_b_check" CHECK (b > 0) + "t_b_check1" CHECK (b > 0) NOT ENFORCED + "t_b_check2" CHECK (b > 0) NOT VALID +Statistics objects: + "partitions_merge_schema.tp_0_1_stat" (dependencies) ON i, b FROM tp_0_1 +Not-null constraints: + "tp_0_1_i_not_null" NOT NULL "i" (inherited) + "t_b_nn" NOT NULL "b" (inherited) NOT VALID +Triggers: + t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t + tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('tp_0_1') + +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1; +\d+ tp_0_1 + Table "partitions_merge_schema.tp_0_1" + Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description +--------+---------+-----------+----------+-------------------------------------------------+----------+-------------+--------------+------------- + i | integer | | not null | | plain | | | + t | text | | | 'default_t'::text | extended | pglz | | + b | bigint | | not null | | plain | | | + d | date | | | generated always as ('01-01-2022'::date) stored | plain | | | +Partition of: t FOR VALUES FROM (0) TO (2) +Partition constraint: ((abs(i) IS NOT NULL) AND (abs(i) >= 0) AND (abs(i) < 2)) +Check constraints: + "t_b_check" CHECK (b > 0) + "t_b_check1" CHECK (b > 0) NOT ENFORCED + "t_b_check2" CHECK (b > 0) NOT VALID +Not-null constraints: + "t_i_not_null" NOT NULL "i" (inherited) + "t_b_nn" NOT NULL "b" (inherited) NOT VALID +Triggers: + t_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW EXECUTE FUNCTION trigger_function('t'), ON TABLE t + +INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3); +NOTICE: trigger(t) called: action = INSERT, when = BEFORE, level = ROW +SELECT tableoid::regclass, * FROM t ORDER BY b; + tableoid | i | t | b | d +----------+---+----------------+---+------------ + tp_0_1 | 0 | default_tp_0_1 | 1 | 01-01-2022 + tp_0_1 | 1 | default_tp_1_2 | 2 | 01-01-2022 + tp_0_1 | 1 | default_t | 3 | 01-01-2022 +(3 rows) + +DROP TABLE t; +DROP FUNCTION trigger_function(); +\set HIDE_TOAST_COMPRESSION true +-- Test MERGE PARTITIONS with not valid foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Should be NOT VALID FOREIGN KEY +\d tp_0_2 + Table "partitions_merge_schema.tp_0_2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + i | integer | | not null | +Partition of: t FOR VALUES FROM (0) TO (2) +Indexes: + "tp_0_2_pkey" PRIMARY KEY, btree (i) +Referenced by: + TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT VALID + +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey; +ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +DETAIL: Key (i)=(2) is not present in table "t". +DROP TABLE t_fk; +DROP TABLE t; +-- Test MERGE PARTITIONS with not enforced foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Should be NOT ENFORCED FOREIGN KEY +\d tp_0_2 + Table "partitions_merge_schema.tp_0_2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + i | integer | | not null | +Partition of: t FOR VALUES FROM (0) TO (2) +Indexes: + "tp_0_2_pkey" PRIMARY KEY, btree (i) +Referenced by: + TABLE "t_fk" CONSTRAINT "t_fk_i_fkey" FOREIGN KEY (i) REFERENCES t(i) NOT ENFORCED + +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED; +ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +DETAIL: Key (i)=(2) is not present in table "t". +DROP TABLE t_fk; +DROP TABLE t; +-- Test for recomputation of stored generated columns. +CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789); +INSERT INTO t VALUES (0), (1); +-- Should be 0 because partition identifier for row with i=0 is different from +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + count +------- + 0 +(1 row) + +-- "tab_id" column (stored generated column) with "tableoid" attribute requires +-- recomputation here. +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +-- Should be 1 because partition identifier for row with i=0 is the same as +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + count +------- + 1 +(1 row) + +DROP TABLE t; +-- Test for generated columns (different order of columns in partitioned table +-- and partitions). +CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i); +CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10); +ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20); +ALTER TABLE t ADD CHECK (g > 0); +ALTER TABLE t ADD CHECK (i > 0); +INSERT INTO t VALUES (5), (15); +ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12; +INSERT INTO t VALUES (16); +-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check" +INSERT INTO t VALUES (0); +ERROR: new row for relation "tp_12" violates check constraint "t_i_check" +DETAIL: Failing row contains (0, virtual). +-- Should be 3 rows: (5), (15), (16): +SELECT i FROM t ORDER BY i; + i +---- + 5 + 15 + 16 +(3 rows) + +-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10: +SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5); + count +------- + 1 +(1 row) + +DROP TABLE t; +RESET search_path; +-- +DROP SCHEMA partitions_merge_schema; +DROP SCHEMA partitions_merge_schema2; diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index cc6d799bcea..633cf20e0a6 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -123,7 +123,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr # The stats test resets stats, so nothing else needing stats access can be in # this group. # ---------- -test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate +test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression compression_lz4 memoize stats predicate numa eager_aggregate # event_trigger depends on create_am and cannot run concurrently with # any test that runs DDL diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql new file mode 100644 index 00000000000..ffb498612a6 --- /dev/null +++ b/src/test/regress/sql/partition_merge.sql @@ -0,0 +1,791 @@ +-- +-- PARTITIONS_MERGE +-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command +-- + +CREATE SCHEMA partitions_merge_schema; +CREATE SCHEMA partitions_merge_schema2; +SET search_path = partitions_merge_schema, public; + +-- +-- BY RANGE partitioning +-- + +-- +-- Test for error codes +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_dec2021 PARTITION OF sales_range FOR VALUES FROM ('2021-12-01') TO ('2021-12-31'); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); + +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-15'); +CREATE TABLE sales_apr_2 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-15') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); + +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; + +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022; +-- ERROR: "sales_apr2022" is not a table +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +-- ERROR: can not merge partition "sales_mar2022" together with partition "sales_jan2022" +-- DETAIL: lower bound of partition "sales_mar2022" is not equal to the upper bound of partition "sales_jan2022" +-- (space between sections sales_jan2022 and sales_mar2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022; +-- ERROR: can not merge partition "sales_jan2022" together with partition "sales_dec2021" +-- DETAIL: lower bound of partition "sales_jan2022" is not equal to the upper bound of partition "sales_dec2021" +-- (space between sections sales_dec2021 and sales_jan2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +-- ERROR: partition with name "sales_feb2022" is already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, partitions_merge_schema.sales_feb2022) INTO sales_feb_mar_apr2022; +--ERROR, sales_apr_2 already exists +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_apr_2; + +CREATE VIEW jan2022v as SELECT * FROM sales_jan2022; +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +DROP VIEW jan2022v; + +-- NO ERROR: test for custom partitions order, source partitions not in the search_path +SET search_path = partitions_merge_schema2, public; +ALTER TABLE partitions_merge_schema.sales_range MERGE PARTITIONS ( + partitions_merge_schema.sales_feb2022, + partitions_merge_schema.sales_mar2022, + partitions_merge_schema.sales_jan2022) INTO sales_jan_feb_mar2022; +SET search_path = partitions_merge_schema, public; + +PREPARE get_partition_info(regclass[]) AS +SELECT c.oid::pg_catalog.regclass, + c.relpersistence, + c.relkind, + i.inhdetachpending, + pg_catalog.pg_get_expr(c.relpartbound, c.oid) +FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i +WHERE c.oid = i.inhrelid AND i.inhparent = ANY($1) +ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', + c.oid::regclass::text COLLATE "C"; + +EXECUTE get_partition_info('{sales_range}'); + +DROP TABLE sales_range; + +-- +-- Add rows into partitioned table, then merge partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); + +SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass); + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_range}'); + +-- check schema-qualified name of the new partition +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO partitions_merge_schema2.sales_feb_mar_apr2022; + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_range}'); + +SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema2'; + +SELECT tableoid::regclass, * FROM sales_range ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + +-- Use indexscan for testing indexes +SET enable_seqscan = OFF; + +EXPLAIN (COSTS OFF) SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01'; +SELECT * FROM partitions_merge_schema2.sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + +RESET enable_seqscan; + +DROP TABLE sales_range; + +-- +-- Merge some partitions into DEFAULT partition +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); + +-- Merge partitions (include DEFAULT partition) into partition with the same +-- name +ALTER TABLE sales_range MERGE PARTITIONS + (sales_jan2022, sales_mar2022, partitions_merge_schema.sales_others) INTO sales_others; + +SELECT * FROM sales_others ORDER BY salesperson_id; + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_range}'); + +DROP TABLE sales_range; + +-- +-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. +-- +CREATE TABLE sales_date (salesperson_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT, + sales_date VARCHAR(10) GENERATED ALWAYS AS + (LPAD(sales_year::text, 4, '0') || '.' || LPAD(sales_month::text, 2, '0') || '.' || LPAD(sales_day::text, 2, '0')) STORED, + sales_department VARCHAR(30) DEFAULT 'Sales department') + PARTITION BY RANGE (sales_year, sales_month, sales_day); + +CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1); +CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1); +CREATE TABLE sales_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1); +CREATE TABLE sales_other PARTITION OF sales_date FOR VALUES FROM (2022, 3, 1) TO (MAXVALUE, MAXVALUE, MAXVALUE); + +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2021, 12, 7), + ('Manager2', 2021, 12, 8), + ('Manager3', 2022, 1, 1), + ('Manager1', 2022, 2, 4), + ('Manager2', 2022, 1, 2), + ('Manager3', 2022, 2, 1), + ('Manager1', 2022, 3, 3), + ('Manager2', 2022, 3, 4), + ('Manager3', 2022, 5, 1); + +SELECT tableoid::regclass, * FROM sales_date; + +ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022; + +INSERT INTO sales_date(salesperson_name, sales_year, sales_month, sales_day) VALUES + ('Manager1', 2022, 1, 10), + ('Manager2', 2022, 2, 10); + +SELECT tableoid::regclass, * FROM sales_date; +DROP TABLE sales_date; + +-- +-- Test: merge partitions of partitioned table with triggers +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); + +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +CREATE TABLE salespeople10_20 PARTITION OF salespeople FOR VALUES FROM (10) TO (20); +CREATE TABLE salespeople20_30 PARTITION OF salespeople FOR VALUES FROM (20) TO (30); +CREATE TABLE salespeople30_40 PARTITION OF salespeople FOR VALUES FROM (30) TO (40); + +INSERT INTO salespeople VALUES (1, 'Poirot'); + +CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN NULL; +END; +$BODY$; + +CREATE TRIGGER salespeople_after_insert_statement_trigger + AFTER INSERT + ON salespeople + FOR EACH STATEMENT + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); + +CREATE TRIGGER salespeople_after_insert_row_trigger + AFTER INSERT + ON salespeople + FOR EACH ROW + EXECUTE PROCEDURE after_insert_row_trigger('salespeople'); + +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (10, 'May'); +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_20 VALUES (19, 'Ivanov'); + +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; + +-- 2 triggers should fire here (row + statement): +INSERT INTO salespeople VALUES (20, 'Smirnoff'); +-- 1 trigger should fire here (row): +INSERT INTO salespeople10_40 VALUES (30, 'Ford'); + +SELECT * FROM salespeople01_10; +SELECT * FROM salespeople10_40; + +DROP TABLE salespeople; +DROP FUNCTION after_insert_row_trigger(); + +-- +-- Test: merge partitions with deleted columns +-- +CREATE TABLE salespeople(salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)) PARTITION BY RANGE (salesperson_id); + +CREATE TABLE salespeople01_10 PARTITION OF salespeople FOR VALUES FROM (1) TO (10); +-- Create partitions with some deleted columns: +CREATE TABLE salespeople10_20(d1 VARCHAR(30), salesperson_id INT PRIMARY KEY, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople20_30(salesperson_id INT PRIMARY KEY, d2 INT, salesperson_name VARCHAR(30)); +CREATE TABLE salespeople30_40(salesperson_id INT PRIMARY KEY, d3 DATE, salesperson_name VARCHAR(30)); + +INSERT INTO salespeople10_20 VALUES ('dummy value 1', 19, 'Ivanov'); +INSERT INTO salespeople20_30 VALUES (20, 101, 'Smirnoff'); +INSERT INTO salespeople30_40 VALUES (31, now(), 'Popov'); + +ALTER TABLE salespeople10_20 DROP COLUMN d1; +ALTER TABLE salespeople20_30 DROP COLUMN d2; +ALTER TABLE salespeople30_40 DROP COLUMN d3; + +ALTER TABLE salespeople ATTACH PARTITION salespeople10_20 FOR VALUES FROM (10) TO (20); +ALTER TABLE salespeople ATTACH PARTITION salespeople20_30 FOR VALUES FROM (20) TO (30); +ALTER TABLE salespeople ATTACH PARTITION salespeople30_40 FOR VALUES FROM (30) TO (40); + +INSERT INTO salespeople VALUES + (1, 'Poirot'), + (10, 'May'), + (30, 'Ford'); + +ALTER TABLE salespeople MERGE PARTITIONS (salespeople10_20, salespeople20_30, salespeople30_40) INTO salespeople10_40; + +select * from salespeople; +select * from salespeople01_10; +select * from salespeople10_40; + +DROP TABLE salespeople; + +-- +-- Test: merge sub-partitions +-- +CREATE TABLE sales_range (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); + +CREATE TABLE sales_apr2022 (salesperson_id INT, salesperson_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr2022_01_10 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'); +CREATE TABLE sales_apr2022_10_20 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'); +CREATE TABLE sales_apr2022_20_30 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); + +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; + +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES + (1, 'May', 1000, '2022-01-31'), + (2, 'Smirnoff', 500, '2022-02-10'), + (3, 'Ford', 2000, '2022-04-30'), + (4, 'Ivanov', 750, '2022-04-13'), + (5, 'Deev', 250, '2022-04-07'), + (6, 'Poirot', 150, '2022-02-11'), + (7, 'Li', 175, '2022-03-08'), + (8, 'Ericsson', 185, '2022-02-23'), + (9, 'Muller', 250, '2022-03-11'), + (10, 'Halder', 350, '2022-01-28'), + (11, 'Trump', 380, '2022-04-06'), + (12, 'Plato', 350, '2022-03-19'), + (13, 'Gandi', 377, '2022-01-09'), + (14, 'Smith', 510, '2022-05-04'); + +SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + +ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all; + +SELECT tableoid::regclass, * FROM sales_apr2022 ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + +DROP TABLE sales_range; + +-- +-- BY LIST partitioning +-- + +-- +-- Test: specific errors for BY LIST partitioning +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; + + +CREATE TABLE sales_list2 (LIKE sales_list) PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT; + + +CREATE TABLE sales_external (LIKE sales_list); +CREATE TABLE sales_external2 (vch VARCHAR(5)); + +-- ERROR: "sales_external" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all; +-- ERROR: "sales_external2" is not a partition of partitioned table "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all; +-- ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_nord2, sales_east) INTO sales_all; + +DROP TABLE sales_external2; +DROP TABLE sales_external; +DROP TABLE sales_list2; +DROP TABLE sales_list; + +-- +-- Test: BY LIST partitioning, MERGE PARTITIONS with data +-- +CREATE TABLE sales_list +(salesperson_id INT GENERATED ALWAYS AS IDENTITY, + salesperson_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); + +CREATE INDEX sales_list_salesperson_name_idx ON sales_list USING btree (salesperson_name); +CREATE INDEX sales_list_sales_state_idx ON sales_list USING btree (sales_state); + +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Oslo', 'St. Petersburg', 'Helsinki'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Lisbon', 'New York', 'Madrid'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; + +INSERT INTO sales_list (salesperson_name, sales_state, sales_amount, sales_date) VALUES + ('Trump', 'Bejing', 1000, '2022-03-01'), + ('Smirnoff', 'New York', 500, '2022-03-03'), + ('Ford', 'St. Petersburg', 2000, '2022-03-05'), + ('Ivanov', 'Warsaw', 750, '2022-03-04'), + ('Deev', 'Lisbon', 250, '2022-03-07'), + ('Poirot', 'Berlin', 1000, '2022-03-01'), + ('May', 'Helsinki', 1200, '2022-03-06'), + ('Li', 'Vladivostok', 1150, '2022-03-09'), + ('May', 'Helsinki', 1200, '2022-03-11'), + ('Halder', 'Oslo', 800, '2022-03-02'), + ('Muller', 'Madrid', 650, '2022-03-05'), + ('Smith', 'Kyiv', 350, '2022-03-10'), + ('Gandi', 'Warsaw', 150, '2022-03-08'), + ('Plato', 'Lisbon', 950, '2022-03-05'); + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_list}'); + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all; + +-- show partitions with conditions: +EXECUTE get_partition_info('{sales_list}'); + +SELECT tableoid::regclass, * FROM sales_list ORDER BY tableoid::regclass::text COLLATE "C", salesperson_id; + +-- Use indexscan for testing indexes after merging partitions +SET enable_seqscan = OFF; + +EXPLAIN (COSTS OFF) SELECT * FROM sales_all WHERE sales_state = 'Warsaw'; +SELECT * FROM sales_all WHERE sales_state = 'Warsaw'; +EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE sales_state = 'Warsaw'; +SELECT * FROM sales_list WHERE sales_state = 'Warsaw'; +EXPLAIN (COSTS OFF) SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov'; +SELECT * FROM sales_list WHERE salesperson_name = 'Ivanov'; + +RESET enable_seqscan; + +DROP TABLE sales_list; + +-- +-- Try to MERGE partitions of another table. +-- +CREATE TABLE t1 (i int, a int, b int, c int) PARTITION BY RANGE (a, b); +CREATE TABLE t1p1 PARTITION OF t1 FOR VALUES FROM (1, 1) TO (1, 2); +CREATE TABLE t2 (i int, t text) PARTITION BY RANGE (t); +CREATE TABLE t2pa PARTITION OF t2 FOR VALUES FROM ('A') TO ('C'); +CREATE TABLE t3 (i int, t text); + +-- ERROR: relation "t1p1" is not a partition of relation "t2" +ALTER TABLE t2 MERGE PARTITIONS (t1p1, t2pa) INTO t2p; +-- ERROR: "t3" is not a partition of partitioned table "t2" +ALTER TABLE t2 MERGE PARTITIONS (t2pa, t3) INTO t2p; + +DROP TABLE t3; +DROP TABLE t2; +DROP TABLE t1; + + +-- +-- Check the partition index name if the partition name is the same as one +-- of the merged partitions. +-- +CREATE TABLE t (i int, PRIMARY KEY(i)) PARTITION BY RANGE (i); + +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +CREATE INDEX tidx ON t(i); +ALTER TABLE t MERGE PARTITIONS (tp_1_2, tp_0_1) INTO tp_1_2; + +-- Indexname values should be 'tp_1_2_pkey' and 'tp_1_2_i_idx'. +\d+ tp_1_2 + +DROP TABLE t; + +-- +-- Try to MERGE partitions of temporary table. +-- +BEGIN; +SHOW search_path; +CREATE TEMP TABLE t (i int) PARTITION BY RANGE (i) ON COMMIT DROP; +CREATE TEMP TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TEMP TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +CREATE TEMP TABLE tp_2_3 PARTITION OF t FOR VALUES FROM (2) TO (3); +CREATE TEMP TABLE tp_3_4 PARTITION OF t FOR VALUES FROM (3) TO (4); + +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; +ALTER TABLE t MERGE PARTITIONS (tp_0_2, tp_2_3) INTO pg_temp.tp_0_3; + +-- Partition should be temporary. +EXECUTE get_partition_info('{t}'); +-- ERROR: cannot create a permanent relation as partition of temporary relation "t" +ALTER TABLE t MERGE PARTITIONS (tp_0_3, tp_3_4) INTO tp_0_4; +ROLLBACK; + +-- +-- Try mixing permanent and temporary partitions. +-- +BEGIN; +SET search_path = partitions_merge_schema, pg_temp, public; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; +EXECUTE get_partition_info('{t}'); +SAVEPOINT s; + +SET search_path = pg_temp, partitions_merge_schema, public; +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +ROLLBACK TO SAVEPOINT s; +SET search_path = partitions_merge_schema, public; +-- Can't merge persistent partitions into a temporary partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO pg_temp.tp_0_2; +ROLLBACK; + +BEGIN; +SET search_path = pg_temp, partitions_merge_schema, public; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SELECT c.oid::pg_catalog.regclass, c.relpersistence FROM pg_catalog.pg_class c WHERE c.oid = 't'::regclass; +EXECUTE get_partition_info('{t}'); + +SET search_path = partitions_merge_schema, pg_temp, public; + +-- Can't merge temporary partitions into a persistent partition +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +ROLLBACK; + +DEALLOCATE get_partition_info; + +-- Check the new partition inherits parent's tablespace +SET search_path = partitions_merge_schema, public; +CREATE TABLE t (i int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) + PARTITION BY RANGE (i) TABLESPACE regress_tblspace; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT tablename, tablespace FROM pg_tables + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename COLLATE "C", tablespace COLLATE "C"; +SELECT tablename, indexname, tablespace FROM pg_indexes + WHERE tablename IN ('t', 'tp_0_2') AND schemaname = 'partitions_merge_schema' + ORDER BY tablename COLLATE "C", indexname COLLATE "C", tablespace COLLATE "C"; +DROP TABLE t; + +-- Check the new partition inherits parent's table access method +SET search_path = partitions_merge_schema, public; +CREATE ACCESS METHOD partitions_merge_heap TYPE TABLE HANDLER heap_tableam_handler; +CREATE TABLE t (i int) PARTITION BY RANGE (i) USING partitions_merge_heap; +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +SELECT c.relname, a.amname +FROM pg_class c JOIN pg_am a ON c.relam = a.oid +WHERE c.oid IN ('t'::regclass, 'tp_0_2'::regclass) +ORDER BY c.relname COLLATE "C"; +DROP TABLE t; +DROP ACCESS METHOD partitions_merge_heap; + +-- Test permission checks. The user needs to own the parent table and all +-- the merging partitions to do the merge. +CREATE ROLE regress_partition_merge_alice; +CREATE ROLE regress_partition_merge_bob; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_alice; +GRANT ALL ON SCHEMA partitions_merge_schema TO regress_partition_merge_bob; + +SET SESSION AUTHORIZATION regress_partition_merge_alice; +CREATE TABLE t (i int) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); + +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- ERROR: must be owner of table t +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +ALTER TABLE t OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- ERROR: must be owner of table tp_0_1 +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- ERROR: must be owner of table tp_1_2 +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob; +SET SESSION AUTHORIZATION regress_partition_merge_bob; +-- Ok: +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; +RESET SESSION AUTHORIZATION; + +DROP TABLE t; + +-- Test: we can't merge partitions with different owners +CREATE TABLE tp_0_1(i int); +ALTER TABLE tp_0_1 OWNER TO regress_partition_merge_alice; +CREATE TABLE tp_1_2(i int); +ALTER TABLE tp_1_2 OWNER TO regress_partition_merge_bob; + +CREATE TABLE t (i int) PARTITION BY RANGE (i); + +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); + +-- Owner is 'regress_partition_merge_alice': +\dt tp_0_1 +-- Owner is 'regress_partition_merge_bob': +\dt tp_1_2 + +-- ERROR: partitions being merged have different owners +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +DROP TABLE t; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_alice; +REVOKE ALL ON SCHEMA partitions_merge_schema FROM regress_partition_merge_bob; +DROP ROLE regress_partition_merge_alice; +DROP ROLE regress_partition_merge_bob; + + +-- Test for hash partitioned table +CREATE TABLE t (i int) PARTITION BY HASH(i); +CREATE TABLE tp1 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 0); +CREATE TABLE tp2 PARTITION OF t FOR VALUES WITH (MODULUS 2, REMAINDER 1); + +-- ERROR: partition of hash-partitioned table cannot be merged +ALTER TABLE t MERGE PARTITIONS (tp1, tp2) INTO tp3; + +-- ERROR: list of partitions to be merged should include at least two partitions +ALTER TABLE t MERGE PARTITIONS (tp1) INTO tp3; + +DROP TABLE t; + + +-- Test for merged partition properties: +-- * STATISTICS is empty +-- * COMMENT is empty +-- * DEFAULTS are the same as DEFAULTS for partitioned table +-- * STORAGE is the same as STORAGE for partitioned table +-- * GENERATED and CONSTRAINTS are the same as GENERATED and CONSTRAINTS for partitioned table +-- * TRIGGERS are the same as TRIGGERS for partitioned table +\set HIDE_TOAST_COMPRESSION false + +CREATE TABLE t +(i int NOT NULL, + t text STORAGE EXTENDED COMPRESSION pglz DEFAULT 'default_t', + b bigint, + d date GENERATED ALWAYS as ('2022-01-01') STORED) PARTITION BY RANGE (abs(i)); +COMMENT ON COLUMN t.i IS 't1.i'; + +CREATE TABLE tp_0_1 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_0_1', + b bigint, + d date GENERATED ALWAYS as ('2022-02-02') STORED); +ALTER TABLE t ATTACH PARTITION tp_0_1 FOR VALUES FROM (0) TO (1); +COMMENT ON COLUMN tp_0_1.i IS 'tp_0_1.i'; + +CREATE TABLE tp_1_2 +(i int NOT NULL, + t text STORAGE MAIN DEFAULT 'default_tp_1_2', + b bigint, + d date GENERATED ALWAYS as ('2022-03-03') STORED); +ALTER TABLE t ATTACH PARTITION tp_1_2 FOR VALUES FROM (1) TO (2); +COMMENT ON COLUMN tp_1_2.i IS 'tp_1_2.i'; + +CREATE STATISTICS t_stat (DEPENDENCIES) on i, b from t; +CREATE STATISTICS tp_0_1_stat (DEPENDENCIES) on i, b from tp_0_1; +CREATE STATISTICS tp_1_2_stat (DEPENDENCIES) on i, b from tp_1_2; + +ALTER TABLE t ADD CONSTRAINT t_b_check CHECK (b > 0); +ALTER TABLE t ADD CONSTRAINT t_b_check1 CHECK (b > 0) NOT ENFORCED; +ALTER TABLE t ADD CONSTRAINT t_b_check2 CHECK (b > 0) NOT VALID; +ALTER TABLE t ADD CONSTRAINT t_b_nn NOT NULL b NOT VALID; + +INSERT INTO tp_0_1(i, t, b) VALUES(0, DEFAULT, 1); +INSERT INTO tp_1_2(i, t, b) VALUES(1, DEFAULT, 2); +CREATE OR REPLACE FUNCTION trigger_function() RETURNS trigger LANGUAGE 'plpgsql' AS +$BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN new; +END; +$BODY$; + +CREATE TRIGGER t_before_insert_row_trigger BEFORE INSERT ON t FOR EACH ROW + EXECUTE PROCEDURE trigger_function('t'); +CREATE TRIGGER tp_0_1_before_insert_row_trigger BEFORE INSERT ON tp_0_1 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_0_1'); +CREATE TRIGGER tp_1_2_before_insert_row_trigger BEFORE INSERT ON tp_1_2 FOR EACH ROW + EXECUTE PROCEDURE trigger_function('tp_1_2'); + +\d+ tp_0_1 +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_1; +\d+ tp_0_1 + +INSERT INTO t(i, t, b) VALUES(1, DEFAULT, 3); +SELECT tableoid::regclass, * FROM t ORDER BY b; +DROP TABLE t; +DROP FUNCTION trigger_function(); +\set HIDE_TOAST_COMPRESSION true + + +-- Test MERGE PARTITIONS with not valid foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT VALID; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Should be NOT VALID FOREIGN KEY +\d tp_0_2 +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk VALIDATE CONSTRAINT t_fk_i_fkey; + +DROP TABLE t_fk; +DROP TABLE t; + +-- Test MERGE PARTITIONS with not enforced foreign key constraint +CREATE TABLE t (i INT PRIMARY KEY) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +INSERT INTO t VALUES (0), (1); +CREATE TABLE t_fk (i INT); +INSERT INTO t_fk VALUES (1), (2); + +ALTER TABLE t_fk ADD CONSTRAINT t_fk_i_fkey FOREIGN KEY (i) REFERENCES t NOT ENFORCED; +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Should be NOT ENFORCED FOREIGN KEY +\d tp_0_2 +-- ERROR: insert or update on table "t_fk" violates foreign key constraint "t_fk_i_fkey" +ALTER TABLE t_fk ALTER CONSTRAINT t_fk_i_fkey ENFORCED; + +DROP TABLE t_fk; +DROP TABLE t; + + +-- Test for recomputation of stored generated columns. +CREATE TABLE t (i int, tab_id int generated always as (tableoid) stored) PARTITION BY RANGE (i); +CREATE TABLE tp_0_1 PARTITION OF t FOR VALUES FROM (0) TO (1); +CREATE TABLE tp_1_2 PARTITION OF t FOR VALUES FROM (1) TO (2); +ALTER TABLE t ADD CONSTRAINT cc CHECK(tableoid <> 123456789); +INSERT INTO t VALUES (0), (1); + +-- Should be 0 because partition identifier for row with i=0 is different from +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + +-- "tab_id" column (stored generated column) with "tableoid" attribute requires +-- recomputation here. +ALTER TABLE t MERGE PARTITIONS (tp_0_1, tp_1_2) INTO tp_0_2; + +-- Should be 1 because partition identifier for row with i=0 is the same as +-- partition identifier for row with i=1. +SELECT count(*) FROM t WHERE i = 0 AND tab_id IN (SELECT tab_id FROM t WHERE i = 1); + +DROP TABLE t; + + +-- Test for generated columns (different order of columns in partitioned table +-- and partitions). +CREATE TABLE t (i int, g int GENERATED ALWAYS AS (i + tableoid::int)) PARTITION BY RANGE (i); +CREATE TABLE tp_1 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +CREATE TABLE tp_2 (g int GENERATED ALWAYS AS (i + tableoid::int), i int); +ALTER TABLE t ATTACH PARTITION tp_1 FOR VALUES FROM (-1) TO (10); +ALTER TABLE t ATTACH PARTITION tp_2 FOR VALUES FROM (10) TO (20); +ALTER TABLE t ADD CHECK (g > 0); +ALTER TABLE t ADD CHECK (i > 0); +INSERT INTO t VALUES (5), (15); + +ALTER TABLE t MERGE PARTITIONS (tp_1, tp_2) INTO tp_12; + +INSERT INTO t VALUES (16); +-- ERROR: new row for relation "tp_12" violates check constraint "t_i_check" +INSERT INTO t VALUES (0); +-- Should be 3 rows: (5), (15), (16): +SELECT i FROM t ORDER BY i; +-- Should be 1 because for the same tableoid (15 + tableoid) = (5 + tableoid) + 10: +SELECT count(*) FROM t WHERE i = 15 AND g IN (SELECT g + 10 FROM t WHERE i = 5); + +DROP TABLE t; + + +RESET search_path; + +-- +DROP SCHEMA partitions_merge_schema; +DROP SCHEMA partitions_merge_schema2;