Updated on 2024-05-07 GMT+08:00

ALTER TABLE PARTITION

Description

Modifies table partitions, including adding, deleting, splitting, merging, clearing, swapping, and renaming partitions, moving partition tablespaces, and modifying partition attributes.

Precautions

  • The tablespace of the added partition cannot be PG_GLOBAL.
  • The name of the added partition must be different from names of existing partitions in the partitioned table.
  • The key value of the added partition must be consistent with the type of partition keys in the partitioned table.
  • If a range partition is added, the key value of the added partition must be greater than the upper limit of the last range partition in the partitioned table.
  • If a list partition is added, the key value of the added partition cannot be the same as that of an existing partition.
  • Hash partitions cannot be added.
  • If the number of partitions in the target partitioned table has reached the maximum (1048575), partitions cannot be added.
  • If a partitioned table has only one partition, the partition cannot be deleted.
  • Use PARTITION FOR() to choose partitions. The number of specified values in the brackets should be the same as the column number in customized partition, and they must be consistent.
  • The Value partitioned table does not support the ALTER PARTITION operation.
  • Partitions cannot be added to an interval partitioned table.
  • Hash partitioned tables do not support splitting, combination, addition, and deletion of partitions.
  • Only the partitioned table owner or a user granted with the ALTER permission can run the ALTER TABLE PARTITION command. The system administrator has this permission by default.
  • Deleting, splitting, merging, clearing, and exchanging partitions will invalidate global indexes. The UPDATE GLOBAL INDEX clause can be used to update the indexes synchronously.
  • If the UPDATE GLOBAL INDEX clause is not used when you delete, split, merge, clear, or exchange partitions, concurrent DML services may report errors due to invalidated indexes.
  • If enable_gpi_auto_update is set to on, the global index is automatically updated even if the UPDATE GLOBAL INDEX clause is not declared.

Syntax

Modifying a partition in a partitioned table includes modifying the table partition itself and the table partition name, and resetting the partition ID.

  • Modify the syntax of the table partition.
    ALTER TABLE [ IF EXISTS ] { table_name  [*] | ONLY table_name | ONLY ( table_name  )}
        action [, ... ];
    action indicates the following clauses for maintaining partitions. For the partition continuity when multiple clauses are used for partition maintenance, GaussDB executes DROP PARTITION and ADD PARTITION first, and then the rest clauses in sequence.
        move_clause  |
        exchange_clause  |
        row_clause  |
        merge_clause  |
        modify_clause  |
        split_clause  |
        add_clause  |
        drop_clause  |
        truncate_clause
    • The move_clause syntax is used to move the partition to a new tablespace.
      MOVE PARTITION { partion_name | FOR ( partition_value [, ...] ) } TABLESPACE tablespacename
    • The exchange_clause syntax is used to move the data from a general table to a specified partition.
      EXCHANGE PARTITION { ( partition_name ) | FOR ( partition_value [, ...] ) } 
          WITH TABLE {[ ONLY ] ordinary_table_name | ordinary_table_name * | ONLY ( ordinary_table_name )} 
          [ { WITH | WITHOUT } VALIDATION ] [ VERBOSE ] [ UPDATE GLOBAL INDEX ]

      The ordinary table and partition whose data is to be exchanged must meet the following requirements:

      • The number of columns of the ordinary table is the same as that of the partition, and their information should be consistent, including: column name, data type, constraint, collation information, storage parameter, and compression information.
      • The compression information of the ordinary table and partition should be consistent.
      • The number of ordinary table indexes is the same as that of local indexes of the partition, and the index information is the same.
      • The number and information of constraints of the ordinary table and partition should be consistent.
      • An ordinary table cannot be a temporary table. A partitioned table can only be a range partitioned table, list partitioned table, hash partitioned table, or interval partitioned table.
      • Ordinary tables and partitioned tables do not support dynamic data masking and row-level security constraints.
      • When the exchange is done, the data and tablespace of the ordinary table and partition are exchanged. The statistics of the ordinary table and partition are no longer inaccurate after the exchange, and they should be analyzed again.
      • A non-partition key cannot be used to create a local unique index. Therefore, if an ordinary table contains a unique index, data cannot be exchanged.

        To exchange data, you can create an intermediate table, insert partition data into the intermediate table, truncate partitions, insert ordinary table data into the partitioned table, drop the ordinary table, and rename the intermediate table.

      • If the DROP COLUMN operation is performed on an ordinary or partitioned table, the deleted column still exists physically. Therefore, you need to ensure that the deleted column of the ordinary table is strictly aligned with that of the partition.
    • The row_clause syntax is used to set row movement of a partitioned table.
      { ENABLE | DISABLE } ROW MOVEMENT
    • The merge_clause syntax is used to merge partitions into one. The maximum number of source partitions that can be merged in a command is 300.
      MERGE PARTITIONS { partition_name } [, ...] INTO PARTITION partition_name 
          [ TABLESPACE tablespacename ] [ UPDATE GLOBAL INDEX ]

      For range partitioning and interval partitioning, the ranges of the source partitions must increase continuously, and the partition name after MERGE can be the same as the name of the last source partition. For list partitioning, there is no such range requirement on the source partitions, and the partition name after MERGE can be the same as that of any source partition. If the partition name after MERGE is the same as that of a source partition, they are considered as the same partition.

      Ustore tables do not support ALTER TABLE MERGE PARTITIONS in transaction blocks and stored procedures.

    • The modify_clause syntax is used to set whether a partitioned index is usable.
      MODIFY PARTITION partition_name { UNUSABLE LOCAL INDEXES | REBUILD UNUSABLE LOCAL INDEXES }
    • The split_clause syntax is used to split one partition into partitions.
      SPLIT PARTITION { partition_name | FOR ( partition_value [, ...] ) } { split_point_clause | no_split_point_clause } [ UPDATE GLOBAL INDEX ]
      • The partition name after SPLIT can be the same as the source partition name, but they are regarded as different partitions.
      • The syntax for specifying the split point for range partitioned tables and interval partitioned tables is as follows:
        AT ( partition_value ) INTO ( PARTITION partition_name [ TABLESPACE tablespacename ] , PARTITION partition_name [ TABLESPACE tablespacename ] )

        The size of the split point should be in the range of partition keys of the partition of to be split. The split point can only split one partition into two new partitions.

      • The syntax for not specifying the split point for range partitioned tables and interval partitioned tables is as follows:
        INTO { ( partition_less_than_item [, ...] ) | ( partition_start_end_item [, ...] ) }
        • The first new partition key specified by partition_less_than_item should be greater than that of the previously split partition (if any), and the last partition key specified by partition_less_than_item should equal that of the partition being split.
        • The first new partition key specified by partition_start_end_item should equal that of the former partition (if any), and the last partition key specified by partition_start_end_item should equal that of the partition being split.
        • partition_less_than_item supports a maximum of 16 partition keys, while partition_start_end_item supports only one partition key. For details about the supported data types, see PARTITION BY RANGE(parti....
        • partition_less_than_item and partition_start_end_item cannot be used in the same statement. There is no restriction on different SPLIT statements.
      • The syntax of partition_less_than_item is as follows (the range of the last partition is not defined, that is, the VALUES LESS THAN (partition_value) part is not defined; by default, the last partition inherits the upper boundary value of the range defined for the source partition):
        PARTITION partition_name VALUES LESS THAN ( { partition_value | MAXVALUE }  [, ...] ) 
            [ TABLESPACE tablespacename ]
      • The syntax of partition_start_end_item is as follows. For details about the constraints, see START END.
        PARTITION partition_name {
                {START(partition_value) END (partition_value) EVERY (interval_value)} |
                {START(partition_value) END ({partition_value | MAXVALUE})} |
                {START(partition_value)} |
                {END({partition_value | MAXVALUE})}
        } [TABLESPACE tablespace_name]
      • The syntax for specifying the split point for a list partitioned table is as follows:
        VALUES ( partition_value_list ) INTO ( PARTITION partition_name [ TABLESPACE tablespacename ] , PARTITION partition_name [ TABLESPACE tablespacename ] )

        The split point must be a non-empty true subset of the source partition. Specifying a split point can only split one partition into two partitions.

      • The syntax for not specifying the split point for a list partitioned table is as follows:
        INTO ( PARTITION partition_name VALUES (partition_value_list) [ TABLESPACE tablespacename ][, ...] )
        • The range of the last partition is not defined, that is, the VALUES (partition_value_list) part is not defined; the partition range is equal to the remaining set of the source partition excluding other level-2 partitions.
        • If no split point is specified, each new partition must be a non-empty true subset of the source partition and does not overlap with each other.
    • The add_clause syntax is used to add one or more partitions to a specified partitioned table.
      ADD {partition_less_than_item | partition_start_end_item| partition_list_item }
      The syntax of partition_list_item is as follows:
      PARTITION partition_name VALUES (list_values_clause) 
          [ TABLESPACE tablespacename ]
      • partition_list_item supports a maximum of 16 partition keys. For details about the supported data types, see PARTITION BY LIST [partit....
      • Interval and hash partitioned tables do not support partition addition.
    • The drop_clause syntax is used to remove a partition from a specified partitioned table.
      DROP PARTITION  { partition_name | FOR (  partition_value [, ...] )  } [ UPDATE GLOBAL INDEX ]
      • Hash partitioned table does not support partition deletion.
      • If a partitioned table has only one partition, the partition cannot be deleted.
    • The truncate_clause syntax is used to remove a specified partition from a partitioned table.
      TRUNCATE PARTITION  { partition_name | FOR (  partition_value [, ...] )  } [ UPDATE GLOBAL INDEX ]
  • The syntax for modifying the name of a partition is as follows:
    ALTER TABLE [ IF EXISTS ] { table_name [*] | ONLY table_name | ONLY ( table_name  )}
        RENAME PARTITION { partion_name | FOR ( partition_value [, ...] ) } TO partition_new_name;
  • Reset a partition ID.
    ALTER TABLE [ IF EXISTS ] { table_name [*] | ONLY table_name | ONLY ( table_name  )} RESET PARTITION;

Parameters

  • table_name

    Specifies the name of a partitioned table.

    Value range: an existing table name

  • partition_name

    Specifies the name of a partition.

    Value range: an existing partition name

  • tablespacename

    Specifies which tablespace the partition moves to.

    Value range: an existing tablespace name

  • partition_value

    Specifies the key value of a partition.

    The value specified by PARTITION FOR ( partition_value [, ...] ) can uniquely identify a partition.

    Value range: partition keys for the partition to be operated.

  • UNUSABLE LOCAL INDEXES

    Sets all the indexes unusable in the partition.

  • REBUILD UNUSABLE LOCAL INDEXES

    Rebuilds all the indexes in the partition.

  • ENABLE/DISABLE ROW MOVEMET

    Sets row movement.

    If the tuple value is updated on the partition key during the UPDATE action, the partition where the tuple is located is altered. Setting this parameter enables error messages to be reported or movement of the tuple between partitions.

    Value range:

    • ENABLE: Row movement is enabled.
    • DISABLE: Row movement is disabled.

    The default value is ENABLE.

  • ordinary_table_name

    Specifies the name of the ordinary table whose data is to be migrated.

    Value range: an existing table name

  • { WITH | WITHOUT } VALIDATION

    Checks whether the ordinary table data meets the specified partition key range of the partition to be migrated.

    Value range:

    • WITH: checks whether the ordinary table data meets the partition key range of the partition to be migrated. If any data does not meet the required range, an error is reported.
    • WITHOUT: does not check whether the ordinary table data meets the partition key range of the partition to be migrated.

    The default value is WITH.

    The check is time consuming, especially when the data volume is large. Therefore, use WITHOUT when you are sure that the current ordinary table data meets the partition key range of the partition to be migrated.

  • VERBOSE

    When VALIDATION is WITH, if the ordinary table contains data that is out of the partition key range, insert the data to the correct partition. If there is no correct partition where the data can be inserted to, an error is reported.

    Only when VALIDATION is WITH, VERBOSE can be specified.

  • partition_new_name

    Specifies the new name of a partition.

    Value range: a string. It must comply with the naming convention.

  • UPDATE GLOBAL INDEX

    If this parameter is used, all global indexes in the partitioned table are updated to ensure that data can be queried correctly using global indexes. If this parameter is not used, all global indexes in the partitioned table will become invalid.

Examples

See Examples in section "CREATE TABLE PARTITION."