Checking for Data Skew
Scenarios
Data skew causes query performance to deteriorate. Before importing all data from a table containing over 10 million records, you are advised to import some of the data and check whether there is data skew and whether the distribution keys need to be changed. Troubleshoot the data skew if any. It is costly to address data skew and change the distribution keys after a large volume of data has been imported.
Background
GaussDB uses a massively parallel processing (MPP) system of the shared-nothing architecture. MPP performs horizontal partitioning to store tuples in the service data table on all DNs using proper distribution policies.
The current product supports multiple user table distribution policies, such as replication, hash, range, and list.
- Replication: Full table data is stored on each DN. You are advised to use the replication distribution policy for tables with 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.
- Range and List: These modes are used in the scenario where users specify the data distribution rule. The target node of the tuple is determined based on the specified column value and the preset range or specific value.
If an inappropriate distribution key is used, there may be data skew when you use the hash policy. Therefore, after this policy is used, data skew check will be performed on user tables to ensure that data is evenly distributed on each DN. You are advised to use the column with few replicated values as the distribution key.
Procedure
- Analyze source data and select candidate distribution keys.
- Select a column from the candidates in 1 as the distribution key to create a target table.
1 2 3 4 5 6 7 8 9 10 11 12 13
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 } ] [ COMPRESS | NOCOMPRESS ] [ TABLESPACE tablespace_name ] [ DISTRIBUTE BY { REPLICATION | { HASH ( column_name [,...] ) | { RANGE ( column_name [, ...] ) SLICE REFERENCES tablename | ( slice_less_than_item [, ...] | slice_start_end_item [, ...] ) | { LIST ( column_name [, ...] ) SLICE REFERENCES tablename | ( slice_values_item [, ...] ) }}} } ]
- 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.
- Check for data skew. (Replace table_name with the actual table name.)
1
openGauss=# 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;
- If data distribution deviation is less than 10% across DNs, data has been 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 step 1, delete the target table, and repeat steps 2 to 5.
- (Optional) If you fail to select an appropriate distribution key after performing the above steps, select multiple columns from the candidates as distribution keys.
Examples
To select an appropriate distribution key for the staffs table, perform the following operations:
- Analyze source data for the staffs table and select the staff_ID, FIRST_NAME, and LAST_NAME columns as candidate distribution keys.
- 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
openGauss=# 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);
- Import a small batch of data to the target table staffs.
As queried by the following statement, there are eight DNs in the cluster. You are advised to import 80,000 records.
1 2 3 4 5
openGauss=# SELECT count(*) FROM pgxc_node where node_type='D'; count ------- 8 (1 row)
- 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
openGauss=# 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)
- As shown in the above query result, the data distribution deviation across DNs is greater than 10%, indicating data skew. Therefore, delete staff_ID from the distribution key candidates and delete the staffs table.
1
openGauss=# DROP TABLE staffs;
- 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
openGauss=# 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);
- 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
openGauss=# 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)
- As shown in the above query result, the data distribution deviation across DNs is less than 10%, indicating even data distribution and a proper distribution key.
- Delete the imported small-batch data.
1
openGauss=# TRUNCATE TABLE staffs;
- Import the full data to complete data migration.
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot