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
On this page

Show all

Creating and Managing Partitioned Tables

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

Context

GaussDB supports range partitioned tables, interval partitioned tables, list partitioned tables, and hash partitioned tables.
  • Range partitioned table: Data within a certain range is mapped to each partition. The range is determined by the partition key specified when the partitioned table is created. This partitioning mode is most commonly used. The partition key is usually a date. For example, sales data is partitioned by month.
  • Interval partitioned table: A special type of range partitioned tables. Compared with range partitioned tables, interval value definition is added. When no matching partition can be found for an inserted record, a partition can be automatically created based on the interval value.
  • List partitioned table: Key values contained in the data are stored in different partitions, and the data is mapped to each partition in sequence. The key values contained in the partitions are specified when the partitioned table is created.
  • Hash partitioned table: Data is mapped to each partition based on the internal hash algorithm. The number of partitions is specified when the partitioned table is created.
A partitioned table has the following advantages over an ordinary table:
  • High query performance: You can specify partitions when querying partitioned tables, improving query efficiency.
  • High availability: If a certain partition in a partitioned table is faulty, data in the other partitions is still available.
  • Easy maintenance: To fix a partitioned table having a faulty partition, you only need to fix the partition.

To convert an ordinary table to a partitioned table, you need to create a partitioned table and import data to it from the ordinary table. When you design tables, plan whether to use partitioned tables based on service requirements.

Procedure

Example 1: Use the default tablespace.
  • Create a partitioned table (assuming that the tpcds schema has been created).
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    29
    gaussdb=# CREATE TABLE tpcds.customer_address
    (
        ca_address_sk       integer                  NOT NULL   ,
        ca_address_id       character(16)            NOT NULL   ,
        ca_street_number    character(10)                       ,
        ca_street_name      character varying(60)               ,
        ca_street_type      character(15)                       ,
        ca_suite_number     character(10)                       ,
        ca_city             character varying(60)               ,
        ca_county           character varying(30)               ,
        ca_state            character(2)                        ,
        ca_zip              character(10)                       ,
        ca_country           character varying(20)               ,
        ca_gmt_offset       numeric(5,2)                        ,
        ca_location_type    character(20)
    )
    
    PARTITION BY RANGE (ca_address_sk)
    (
            PARTITION P1 VALUES LESS THAN(5000),
            PARTITION P2 VALUES LESS THAN(10000),
            PARTITION P3 VALUES LESS THAN(15000),
            PARTITION P4 VALUES LESS THAN(20000),
            PARTITION P5 VALUES LESS THAN(25000),
            PARTITION P6 VALUES LESS THAN(30000),
            PARTITION P7 VALUES LESS THAN(40000),
            PARTITION P8 VALUES LESS THAN(MAXVALUE)
    )
    ENABLE ROW MOVEMENT;
    

    If the following information is displayed, the creation is successful:

    1
    CREATE TABLE
    
  • Insert data.

    Insert data from the tpcds.customer_address table to the tpcds.web_returns_p2 table.

    Suppose that the backup table tpcds.web_returns_p2 of the tpcds.customer_address table has been created in the database. You can insert the data of the tpcds.customer_address table into the backup table tpcds.web_returns_p2.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    29
    30
    31
    32
    gaussdb=# CREATE TABLE tpcds.web_returns_p2
    (
        ca_address_sk       integer                  NOT NULL   ,
        ca_address_id       character(16)            NOT NULL   ,
        ca_street_number    character(10)                       ,
        ca_street_name      character varying(60)               ,
        ca_street_type      character(15)                       ,
        ca_suite_number     character(10)                       ,
        ca_city             character varying(60)               ,
        ca_county           character varying(30)               ,
        ca_state            character(2)                        ,
        ca_zip              character(10)                       ,
        ca_country           character varying(20)               ,
        ca_gmt_offset       numeric(5,2)                        ,
        ca_location_type    character(20)
    )
    
    PARTITION BY RANGE (ca_address_sk)
    (
            PARTITION P1 VALUES LESS THAN(5000),
            PARTITION P2 VALUES LESS THAN(10000),
            PARTITION P3 VALUES LESS THAN(15000),
            PARTITION P4 VALUES LESS THAN(20000),
            PARTITION P5 VALUES LESS THAN(25000),
            PARTITION P6 VALUES LESS THAN(30000),
            PARTITION P7 VALUES LESS THAN(40000),
            PARTITION P8 VALUES LESS THAN(MAXVALUE)
    )
    ENABLE ROW MOVEMENT;
    CREATE TABLE
    gaussdb=# INSERT INTO tpcds.web_returns_p2 SELECT * FROM tpcds.customer_address;
    INSERT 0 0
    
  • Modify the row movement attributes of the partitioned table.
    1
    2
    gaussdb=# ALTER TABLE tpcds.web_returns_p2 DISABLE ROW MOVEMENT;
    ALTER TABLE
    
  • Delete a partition.
    Delete partition P8.
    1
    2
    gaussdb=# ALTER TABLE tpcds.web_returns_p2 DROP PARTITION P8;
    ALTER TABLE
    
  • Add a partition.

    Add partition P8 and set its range to [40000,MAXVALUE).

    1
    2
    gaussdb=# ALTER TABLE tpcds.web_returns_p2 ADD PARTITION P8 VALUES LESS THAN (MAXVALUE);
    ALTER TABLE
    
  • Rename partitions.
    • Rename partition P8 to P_9.
      1
      2
      gaussdb=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION P8 TO P_9;
      ALTER TABLE
      
    • Rename partition P_9 to P8.
      1
      2
      gaussdb=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION FOR (40000) TO P8;
      ALTER TABLE
      
  • Query a partition.
    Query partition P6.
    1
    2
    gaussdb=# SELECT * FROM tpcds.web_returns_p2 PARTITION (P6);
    gaussdb=# SELECT * FROM tpcds.web_returns_p2 PARTITION FOR (35888);
    
  • Delete a partitioned table and its tablespaces.
    1
    2
    3
    4
    gaussdb=# DROP TABLE tpcds.customer_address;
    DROP TABLE
    gaussdb=# DROP TABLE tpcds.web_returns_p2;
    DROP TABLE
    

Example 2: Use a user-defined tablespace (assuming that the tpcds schema has been created).

Perform the following operations on a range partitioned table:
  • Create tablespaces.
    1
    2
    3
    4
    gaussdb=# CREATE TABLESPACE example1 RELATIVE LOCATION 'tablespace1/tablespace_1';
    gaussdb=# CREATE TABLESPACE example2 RELATIVE LOCATION 'tablespace2/tablespace_2';
    gaussdb=# CREATE TABLESPACE example3 RELATIVE LOCATION 'tablespace3/tablespace_3';
    gaussdb=# CREATE TABLESPACE example4 RELATIVE LOCATION 'tablespace4/tablespace_4';
    

    If the following information is displayed, the creation is successful:

    1
    CREATE TABLESPACE
    
  • Create a partitioned table.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    29
    30
    gaussdb=# CREATE TABLE tpcds.customer_address
    (
        ca_address_sk       integer                  NOT NULL   ,
        ca_address_id       character(16)            NOT NULL   ,
        ca_street_number    character(10)                       ,
        ca_street_name      character varying(60)               ,
        ca_street_type      character(15)                       ,
        ca_suite_number     character(10)                       ,
        ca_city             character varying(60)               ,
        ca_county           character varying(30)               ,
        ca_state            character(2)                        ,
        ca_zip              character(10)                       ,
        ca_country           character varying(20)               ,
        ca_gmt_offset       numeric(5,2)                        ,
        ca_location_type    character(20)
    )
    TABLESPACE example1
    
    PARTITION BY RANGE (ca_address_sk)
    (
            PARTITION P1 VALUES LESS THAN(5000),
            PARTITION P2 VALUES LESS THAN(10000),
            PARTITION P3 VALUES LESS THAN(15000),
            PARTITION P4 VALUES LESS THAN(20000),
            PARTITION P5 VALUES LESS THAN(25000),
            PARTITION P6 VALUES LESS THAN(30000),
            PARTITION P7 VALUES LESS THAN(40000),
            PARTITION P8 VALUES LESS THAN(MAXVALUE) TABLESPACE example2
    )
    ENABLE ROW MOVEMENT;
    

    If the following information is displayed, the creation is successful:

    1
    CREATE TABLE
    
  • Insert data.

    Insert data from the tpcds.customer_address table to the tpcds.web_returns_p2 table.

    Suppose that the backup table tpcds.web_returns_p2 of the tpcds.customer_address table has been created in the database. You can insert the data of the tpcds.customer_address table into the backup table tpcds.web_returns_p2.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    29
    30
    31
    32
    gaussdb=# CREATE TABLE tpcds.web_returns_p2
    (
        ca_address_sk       integer                  NOT NULL   ,
        ca_address_id       character(16)            NOT NULL   ,
        ca_street_number    character(10)                       ,
        ca_street_name      character varying(60)               ,
        ca_street_type      character(15)                       ,
        ca_suite_number     character(10)                       ,
        ca_city             character varying(60)               ,
        ca_county           character varying(30)               ,
        ca_state            character(2)                        ,
        ca_zip              character(10)                       ,
        ca_country           character varying(20)               ,
        ca_gmt_offset       numeric(5,2)                        ,
        ca_location_type    character(20)
    )
    TABLESPACE example1
    PARTITION BY RANGE (ca_address_sk)
    (
            PARTITION P1 VALUES LESS THAN(5000),
            PARTITION P2 VALUES LESS THAN(10000),
            PARTITION P3 VALUES LESS THAN(15000),
            PARTITION P4 VALUES LESS THAN(20000),
            PARTITION P5 VALUES LESS THAN(25000),
            PARTITION P6 VALUES LESS THAN(30000),
            PARTITION P7 VALUES LESS THAN(40000),
            PARTITION P8 VALUES LESS THAN(MAXVALUE) TABLESPACE example2
    )
    ENABLE ROW MOVEMENT;
    CREATE TABLE
    gaussdb=# INSERT INTO tpcds.web_returns_p2 SELECT * FROM tpcds.customer_address;
    INSERT 0 0
    
  • Modify the row movement attributes of the partitioned table.
    1
    2
    gaussdb=# ALTER TABLE tpcds.web_returns_p2 DISABLE ROW MOVEMENT;
    ALTER TABLE
    
  • Delete a partition.
    Delete partition P8.
    1
    2
    gaussdb=# ALTER TABLE tpcds.web_returns_p2 DROP PARTITION P8;
    ALTER TABLE
    
  • Add a partition.

    Add partition P8 and set its range to [40000,MAXVALUE).

    1
    2
    gaussdb=# ALTER TABLE tpcds.web_returns_p2 ADD PARTITION P8 VALUES LESS THAN (MAXVALUE);
    ALTER TABLE
    
  • Rename partitions.
    • Rename partition P8 to P_9.
      1
      2
      gaussdb=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION P8 TO P_9;
      ALTER TABLE
      
    • Rename partition P_9 to P8.
      1
      2
      gaussdb=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION FOR (40000) TO P8;
      ALTER TABLE
      
  • Change the tablespace of a partition.
    • Change the tablespace of partition P6 to example3.
      1
      2
      gaussdb=#  ALTER TABLE tpcds.web_returns_p2 MOVE PARTITION P6 TABLESPACE example3;
      ALTER TABLE
      
    • Change the tablespace of partition P4 to example4:
      1
      2
      gaussdb=#  ALTER TABLE tpcds.web_returns_p2 MOVE PARTITION P4 TABLESPACE example4;
      ALTER TABLE
      
  • Query a partition.
    Query partition P6.
    1
    2
    gaussdb=# SELECT * FROM tpcds.web_returns_p2 PARTITION (P6);
    gaussdb=# SELECT * FROM tpcds.web_returns_p2 PARTITION FOR (35888);
    
  • Delete a partitioned table and its tablespaces.
    1
    2
    3
    4
    5
    6
    7
    8
    9
    gaussdb=# DROP TABLE tpcds.customer_address;
    DROP TABLE
    gaussdb=# DROP TABLE tpcds.web_returns_p2;
    DROP TABLE
    gaussdb=# DROP TABLESPACE example1;
    gaussdb=# DROP TABLESPACE example2;
    gaussdb=# DROP TABLESPACE example3;
    gaussdb=# DROP TABLESPACE example4;
    DROP TABLESPACE
    

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