HomeMogDBMogDB StackUqbar
v3.1

Documentation:v3.1

Supported Versions:

ALTER TABLE PARTITION

Function

ALTER TABLE PARTITION modifies table partitions, including adding, deleting, splitting, merging partitions, and altering partition attributes.

Precautions

  • The tablespace of the added partition cannot be PG_GLOBAL.

  • The name of the added partition must be different from the 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 partitions, and they must be consistent.

  • The Value partitioned table does not support the Alter Partition operation.

  • Column-store tables and row-store tables cannot be partitioned.

  • Partitions cannot be added to an interval partitioned table.

  • Hash partitioned tables do not support splitting, combination, addition, and deletion of partitions.

  • List partitioned tables do not support partition splitting or partition combination.

  • Only the owner of a partitioned table or users granted with the ALTER permission on the partitioned table can run the ALTER TABLE PARTITION command. The system administrator has the permission to run the command by default.

Syntax

  • Modify the syntax of the table partition.

    AlterTable ::= 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, MogDB does DROP PARTITION and then ADD PARTITION, and finally runs the rest clauses in sequence.

    action ::= 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_clause ::= 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_clause ::= 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 and information of indexes of the ordinary table and partition should be consistent.

    • 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, or hash partitioned table.

    • Ordinary tables and partitioned tables do not support dynamic data masking and row-level access control constraints.

    • List partitioned tables and hash partitioned tables cannot be column-store.

    • List, hash, and range partitioned tables support exchange_clause.

      Notice:

      • When the exchange is done, the data and tablespace of the ordinary table and partition are exchanged. The statistics about ordinary tables and partitions become unreliable, 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.
    • The row_clause syntax is used to set row movement of a partitioned table.

      row_clause ::= { ENABLE | DISABLE } ROW MOVEMENT
    • The merge_clause syntax is used to merge partitions into one.

      merge_clause ::= MERGE PARTITIONS { partition_name } [, ...] INTO PARTITION partition_name
          [ TABLESPACE tablespacename ][ UPDATE GLOBAL INDEX ]
    • The modify_clause syntax is used to set whether a partition index is usable.

      modify_clause ::= MODIFY PARTITION partition_name { UNUSABLE LOCAL INDEXES | REBUILD UNUSABLE LOCAL INDEXES }
    • The split_clause syntax is used to split one partition into partitions.

      split_clause ::= SPLIT PARTITION { partition_name | FOR ( partition_value [, ...] ) } { split_point_clause | no_split_point_clause }[ UPDATE GLOBAL INDEX ]
    • The split_point_clause syntax is used to specify a split point.

      split_point_clause ::= AT ( partition_value ) INTO ( PARTITION partition_name [ TABLESPACE tablespacename ] , PARTITION partition_name [ TABLESPACE tablespacename ] )

      img NOTICE:

      • Column-store tables and row-store tables cannot be partitioned.
      • The size of the split point should be in the range of partition keys of the partition to be split. The split point can only split one partition into two new partitions.
    • The no_split_point_clause syntax does not specify a split point.

      no_split_point_clause ::= INTO { ( partition_less_than_item [, ...] ) | ( partition_start_end_item [, ...] ) }

      img NOTICE:

      • 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 4 partition keys, while partition_start_end_item supports only one partition key. For details about the supported data types, see CREATE TABLE PARTITON.
      • partition_less_than_item and partition_start_end_item cannot be used in the same statement.
    • The syntax of partition_less_than_item is as follows:

      partition_less_than_item ::= 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 CREATE TABLE PARTITON.

      partition_start_end_item ::= 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 add_clause syntax is used to add one or more partitions to a specified partitioned table.

      add_clause ::= ADD PARTITION ( partition_col1_name = partition_col1_value [ partition_col2_name = partition_col2_value ] [, ...] )
              [ LOCATION 'location1' ]
                  [ PARTITION ( partition_colA_name = partition_colA_value [ partition_colB_name = partition_colB_value ] [, ...] ) ]
                  [ LOCATION 'location2' ]
                  ADD {partition_less_than_item | partition_start_end_item| partition_list_item }

      The syntax of partition_list_item is as follows:

      partition_list_item ::= PARTITION partition_name VALUES ( list_values_clause )
          [ TABLESPACE tablespacename ]

      img NOTICE:

      • partition_list_item supports only one partition key. For details about the data types supported by partition_list_item, 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_clause ::= DROP PARTITION  { partition_name | FOR (  partition_value [, ...] )  } [ UPDATE GLOBAL INDEX ]

      img NOTICE:

      • Hash partitioned table does not support partition deletion.
    • The truncate_clause syntax is used to remove a specified partition from a partitioned table.

      truncate_clause ::= TRUNCATE PARTITION  { partition_name | FOR (  partition_value [, ...] )  } [ UPDATE GLOBAL INDEX ]
  • The syntax for modifying the name of a partition is as follows:

    AlterTable ::= ALTER TABLE [ IF EXISTS ] { table_name [*] | ONLY table_name | ONLY ( table_name  )}
        RENAME PARTITION { partion_name | FOR ( partition_value [, ...] ) } TO partition_new_name;

Parameter Description

  • table_name

    Specifies the name of a partitioned table.

    Value range: an existing partitioned 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 renamed.

  • 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.

    img NOTICE: 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 identifier naming convention.

Example

See Examples in CREATE TABLE PARTITION.

CREATE TABLE PARTITIONDROP TABLE

Copyright © 2011-2024 www.enmotech.com All rights reserved.