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

Checking for Data Skew

Updated on 2022-08-16 GMT+08:00

Scenarios

Data skew causes the query performance to deteriorate. Before importing all the data from a table consisting of over 10 million records, you are advised to import some of the data and check whether data skew occurs and whether the distribution keys need to be changed. Troubleshoot the problems if any. It is costly to address data skew and change the distribution keys after a large amount of data has been imported.

Background

GaussDB(DWS) uses a massively parallel processing (MPP) system of the shared-nothing architecture. The MPP performs horizontal partitioning to store tuples in service data tables on all DNs using proper distribution policies.

The following user table distribution policies are supported:

  • Replication: stores a full table on each DN. You are advised to use the replication mode for tables containing a small volume of data.
  • Hash: A distribution key must be specified for a user table. When a record is inserted, the system hashes it based on the distribution key and then stores it on the corresponding DN. You are advised to use the hash distribution policy for tables with a large volume of data.

If an inappropriate distribution key is used, data skew may occur when you use the hash policy. Check for data skew when you use the hash distribution policy so that data can be evenly distributed to each DN. You are advised to use the column with few replicated values as the distribution key.

Procedure

  1. Analyze data source features and select candidate distribution columns that have more distinct values and evenly distributed data.
  2. Select a candidate column from 1 to create a target table.

    1
    2
    3
    4
    5
    6
    7
    8
    9
    CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] table_name 
        ({ column_name data_type [ compress_mode ] [ COLLATE collation ] [ column_constraint [ ... ] ]
        | table_constraint    | LIKE source_table [ like_option [...] ] }
        [, ... ])    [ WITH ( {storage_parameter = value} [, ... ] ) ]
        [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
        [ COMPRESS | NOCOMPRESS ]    [ TABLESPACE tablespace_name ]
        [ DISTRIBUTE BY { REPLICATION 
      
                        | { HASH ( column_name [,...] ) } } ];
    

  3. Import a small batch of data to the target table.

    When importing a single data file, you can evenly split this file and import a part of it to check for the data skew in the target table.

  4. Check for data skew. (Replace table_name with the actual table name.)

    1
    SELECT a.count,b.node_name FROM (SELECT count(*) AS count,xc_node_id FROM table_name GROUP BY xc_node_id) a, pgxc_node b WHERE a.xc_node_id=b.node_id ORDER BY a.count desc;
    

  5. If the data distribution deviation is less than 10% across DNs, data is evenly distributed and an appropriate distribution key has been selected. Delete the small batch of imported data and import full data to complete data migration.

    If data distribution deviation across DNs is greater than or equal to 10%, data skew occurs. Remove this distribution key from the candidates in 1, delete the target table, and repeat 2 through 5.

    NOTE:

    The data distribution deviation indicates the difference between the actual data volume on DNs and the average data volume on DNs.

  6. (Optional) If you fail to select an appropriate distribution key after performing the preceding steps, select multiple columns from the candidates as distribution keys.

Examples

Assume you want to select an appropriate distribution key for the staffs table.

  1. Analyze the source data for the staffs table and select the staff_ID, FIRST_NAME, and LAST_NAME columns as candidate distribution keys.
  2. Select the staff_ID column as the distribution key and create the target table staffs.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    CREATE TABLE staffs
    (
      staff_ID       NUMBER(6) not null,
      FIRST_NAME     VARCHAR2(20),
      LAST_NAME      VARCHAR2(25),
      EMAIL          VARCHAR2(25),
      PHONE_NUMBER   VARCHAR2(20),
      HIRE_DATE      DATE,
      employment_ID  VARCHAR2(10),
      SALARY         NUMBER(8,2),
      COMMISSION_PCT NUMBER(2,2),
      MANAGER_ID     NUMBER(6),
      section_ID     NUMBER(4)
    )   
    DISTRIBUTE BY hash(staff_ID);
    
  3. Import a small batch of data to the target table staffs.
    There are eight DNs in the cluster based on the following query, and you are advised to import 80,000 records.
    1
    2
    3
    4
    5
    SELECT count(*) FROM pgxc_node where node_type='D';
     count 
    -------
         8
    (1 row)
    
  4. Verify the data skew of the target table staffs whose distribution key is staff_ID:
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    SELECT a.count,b.node_name FROM (select count(*) as count,xc_node_id FROM staffs GROUP BY xc_node_id) a, pgxc_node b WHERE a.xc_node_id=b.node_id ORDER BY a.count desc;
    count | node_name
    ------+-----------
    11010 | datanode4
    10000 | datanode3
    12001 | datanode2
     8995 | datanode1
    10000 | datanode5
     7999 | datanode6
     9995 | datanode7
    10000 | datanode8
    (8 rows)
    
  5. The preceding query result indicates that the distribution deviation across DNs is greater than 10%. The data skew occurs. Therefore, delete staff_ID from the distribution key candidates and delete the staffs table.
    1
    DROP TABLE staffs;
    
  6. Use staff_ID, FIRST_NAME, and LAST_NAME as distribution keys and create the target table staffs.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    CREATE TABLE staffs
    (  
      staff_ID       NUMBER(6) not null,
      FIRST_NAME     VARCHAR2(20),
      LAST_NAME      VARCHAR2(25),
      EMAIL          VARCHAR2(25),
      PHONE_NUMBER   VARCHAR2(20),
      HIRE_DATE      DATE,
      employment_ID  VARCHAR2(10),
      SALARY         NUMBER(8,2),
      COMMISSION_PCT NUMBER(2,2),
      MANAGER_ID     NUMBER(6),
      section_ID     NUMBER(4)
    ) 
    DISTRIBUTE BY hash(staff_ID,FIRST_NAME,LAST_NAME);
    
  7. Verify the data skew of the target table staffs whose distribution keys are staff_ID, FIRST_NAME, and LAST_NAME.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    SELECT a.count,b.node_name FROM (select count(*) as count,xc_node_id FROM staffs GROUP BY xc_node_id) a, pgxc_node b WHERE a.xc_node_id=b.node_id ORDER BY a.count desc;
    count | node_name
    ------+-----------
    10010 | datanode4
    10000 | datanode3
    10001 | datanode2
     9995 | datanode1
    10000 | datanode5
     9999 | datanode6
     9995 | datanode7
    10000 | datanode8
    (8 rows)
    
  8. The preceding query result indicates that the data deviation across DNs is less than 10%. The data is evenly distributed and the appropriate distribution keys have been selected.
  9. Delete the imported small-batch data.
    1
    TRUNCATE TABLE staffs;
    
  10. Import the full data to complete data migration.

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