Compute
Elastic Cloud Server
Huawei Cloud Flexus
Bare Metal Server
Auto Scaling
Image Management Service
Dedicated Host
FunctionGraph
Cloud Phone Host
Huawei Cloud EulerOS
Networking
Virtual Private Cloud
Elastic IP
Elastic Load Balance
NAT Gateway
Direct Connect
Virtual Private Network
VPC Endpoint
Cloud Connect
Enterprise Router
Enterprise Switch
Global Accelerator
Management & Governance
Cloud Eye
Identity and Access Management
Cloud Trace Service
Resource Formation Service
Tag Management Service
Log Tank Service
Config
OneAccess
Resource Access Manager
Simple Message Notification
Application Performance Management
Application Operations Management
Organizations
Optimization Advisor
IAM Identity Center
Cloud Operations Center
Resource Governance Center
Migration
Server Migration Service
Object Storage Migration Service
Cloud Data Migration
Migration Center
Cloud Ecosystem
KooGallery
Partner Center
User Support
My Account
Billing Center
Cost Center
Resource Center
Enterprise Management
Service Tickets
HUAWEI CLOUD (International) FAQs
ICP Filing
Support Plans
My Credentials
Customer Operation Capabilities
Partner Support Plans
Professional Services
Analytics
MapReduce Service
Data Lake Insight
CloudTable Service
Cloud Search Service
Data Lake Visualization
Data Ingestion Service
GaussDB(DWS)
DataArts Studio
Data Lake Factory
DataArts Lake Formation
IoT
IoT Device Access
Others
Product Pricing Details
System Permissions
Console Quick Start
Common FAQs
Instructions for Associating with a HUAWEI CLOUD Partner
Message Center
Security & Compliance
Security Technologies and Applications
Web Application Firewall
Host Security Service
Cloud Firewall
SecMaster
Anti-DDoS Service
Data Encryption Workshop
Database Security Service
Cloud Bastion Host
Data Security Center
Cloud Certificate Manager
Edge Security
Managed Threat Detection
Blockchain
Blockchain Service
Web3 Node Engine Service
Media Services
Media Processing Center
Video On Demand
Live
SparkRTC
MetaStudio
Storage
Object Storage Service
Elastic Volume Service
Cloud Backup and Recovery
Storage Disaster Recovery Service
Scalable File Service Turbo
Scalable File Service
Volume Backup Service
Cloud Server Backup Service
Data Express Service
Dedicated Distributed Storage Service
Containers
Cloud Container Engine
SoftWare Repository for Container
Application Service Mesh
Ubiquitous Cloud Native Service
Cloud Container Instance
Databases
Relational Database Service
Document Database Service
Data Admin Service
Data Replication Service
GeminiDB
GaussDB
Distributed Database Middleware
Database and Application Migration UGO
TaurusDB
Middleware
Distributed Cache Service
API Gateway
Distributed Message Service for Kafka
Distributed Message Service for RabbitMQ
Distributed Message Service for RocketMQ
Cloud Service Engine
Multi-Site High Availability Service
EventGrid
Dedicated Cloud
Dedicated Computing Cluster
Business Applications
Workspace
ROMA Connect
Message & SMS
Domain Name Service
Edge Data Center Management
Meeting
AI
Face Recognition Service
Graph Engine Service
Content Moderation
Image Recognition
Optical Character Recognition
ModelArts
ImageSearch
Conversational Bot Service
Speech Interaction Service
Huawei HiLens
Video Intelligent Analysis Service
Developer Tools
SDK Developer Guide
API Request Signing Guide
Terraform
Koo Command Line Interface
Content Delivery & Edge Computing
Content Delivery Network
Intelligent EdgeFabric
CloudPond
Intelligent EdgeCloud
Solutions
SAP Cloud
High Performance Computing
Developer Services
ServiceStage
CodeArts
CodeArts PerfTest
CodeArts Req
CodeArts Pipeline
CodeArts Build
CodeArts Deploy
CodeArts Artifact
CodeArts TestPlan
CodeArts Check
CodeArts Repo
Cloud Application Engine
MacroVerse aPaaS
KooMessage
KooPhone
KooDrive

ALTER TABLE PARTITION

Updated on 2024-10-14 GMT+08:00

Function

ALTER TABLE PARTITION modifies table partitions, including adding, deleting, splitting, merging, clearing, swapping, and renaming partitions, moving partition tablespaces, and modifying partition attributes.

Precautions

  • The tablespace for the added partition cannot be PG_GLOBAL.
  • The name of the added partition must be different from names of existing partitions in the partition table.
  • The partition key of the added partition must be the same type as that of the partitioned table. The key value of the added partition must exceed the upper limit of the last partition range.
  • If the number of partitions in the target partitioned table reaches the maximum (1048575), no more partitions can 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 partition table does not support the Alter Partition operation.
  • Column-store tables and row-store tables cannot be partitioned.
  • 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.

Syntax

  • Modify the syntax of the table partition.
    1
    2
    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 does DROP PARTITION and then ADD PARTITION, and finally runs the rest clauses in sequence.
    1
    2
    3
    4
    5
    6
    7
    8
    move_clause  |
        exchange_clause  |
        row_clause  |
        merge_clause  |
        modify_clause  |
        split_clause  |
        add_clause  |
        drop_clause
    
    • The move_clause syntax is used to move the partition to a new tablespace.
      1
      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.
      1
      2
      3
      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 distribution key 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.
      • The ordinary table cannot be a temporary table.
      • When the built-in security policy is enabled, a common table cannot contain columns bound to a dynamic data anonymization policy.

      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. 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.
      1
      { ENABLE | DISABLE } ROW MOVEMENT
      
    • The merge_clause syntax is used to merge partitions into one.
      1
      2
      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.
      1
      MODIFY PARTITION partition_name { UNUSABLE LOCAL INDEXES | REBUILD UNUSABLE LOCAL INDEXES }
      
    • The split_clause syntax is used to split one partition into partitions.
      1
      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.
        1
        AT ( partition_value ) INTO ( PARTITION partition_name [ TABLESPACE tablespacename ] , PARTITION partition_name [ TABLESPACE tablespacename ] )
        
        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 of 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.
        1
        INTO { ( partition_less_than_item [, ...] ) | ( partition_start_end_item [, ...] ) }
        
        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 •PARTITION BY RANGE(part....
        • 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:
        1
        2
        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 partition_start_end_item syntax.
        1
        2
        3
        4
        5
        6
        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.
      1
      2
      3
      4
      5
      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}
      
    • The drop_clause syntax is used to remove a partition from a specified partitioned table.
      1
      DROP PARTITION  { partition_name | FOR (  partition_value [, ...] )  } [ UPDATE GLOBAL INDEX ]
      
  • The syntax for modifying the name of a partition is as follows:
    1
    2
    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 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.

    By default, this parameter is disabled.

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

    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 naming convention.

  • UPDATE GLOBAL INDEX

    If this parameter is used, all global indexes in a partitioned table are updated to ensure that correct data can be queried using global indexes.

    If this parameter is not used, all global indexes in a partitioned table will become invalid.

Examples

See Examples in CREATE TABLE PARTITION.

We use cookies to improve our site and your experience. By continuing to browse our site you accept our cookie policy. Find out more

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback