Skip to content

Commit 388d74c

Browse files
authored
distribute-table: support to scatter the region distribution of the given table and engine (#20345)
1 parent 4eb672c commit 388d74c

File tree

5 files changed

+298
-0
lines changed

5 files changed

+298
-0
lines changed

TOC.md

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -811,6 +811,7 @@
811811
- [`BATCH`](/sql-statements/sql-statement-batch.md)
812812
- [`BEGIN`](/sql-statements/sql-statement-begin.md)
813813
- [`CALIBRATE RESOURCE`](/sql-statements/sql-statement-calibrate-resource.md)
814+
- [`CANCEL DISTRIBUTION JOB`](/sql-statements/sql-statement-cancel-distribution-job.md)
814815
- [`CANCEL IMPORT JOB`](/sql-statements/sql-statement-cancel-import-job.md)
815816
- [`CANCEL TRAFFIC JOBS`](/sql-statements/sql-statement-cancel-traffic-jobs.md)
816817
- [`COMMIT`](/sql-statements/sql-statement-commit.md)
@@ -829,6 +830,7 @@
829830
- [`DELETE`](/sql-statements/sql-statement-delete.md)
830831
- [`DESC`](/sql-statements/sql-statement-desc.md)
831832
- [`DESCRIBE`](/sql-statements/sql-statement-describe.md)
833+
- [`DISTRIBUTE TABLE`](/sql-statements/sql-statement-distribute-table.md)
832834
- [`DO`](/sql-statements/sql-statement-do.md)
833835
- [`DROP BINDING`](/sql-statements/sql-statement-drop-binding.md)
834836
- [`DROP DATABASE`](/sql-statements/sql-statement-drop-database.md)
@@ -893,6 +895,7 @@
893895
- [`SHOW CREATE TABLE`](/sql-statements/sql-statement-show-create-table.md)
894896
- [`SHOW CREATE USER`](/sql-statements/sql-statement-show-create-user.md)
895897
- [`SHOW DATABASES`](/sql-statements/sql-statement-show-databases.md)
898+
- [`SHOW DISTRIBUTION JOBS`](/sql-statements/sql-statement-show-distribution-jobs.md)
896899
- [`SHOW ENGINES`](/sql-statements/sql-statement-show-engines.md)
897900
- [`SHOW ERRORS`](/sql-statements/sql-statement-show-errors.md)
898901
- [`SHOW FIELDS FROM`](/sql-statements/sql-statement-show-fields-from.md)
@@ -915,6 +918,7 @@
915918
- [`SHOW STATS_META`](/sql-statements/sql-statement-show-stats-meta.md)
916919
- [`SHOW STATS_TOPN`](/sql-statements/sql-statement-show-stats-topn.md)
917920
- [`SHOW STATUS`](/sql-statements/sql-statement-show-status.md)
921+
- [`SHOW TABLE DISTRIBUTION`](/sql-statements/sql-statement-show-table-distribution.md)
918922
- [`SHOW TABLE NEXT_ROW_ID`](/sql-statements/sql-statement-show-table-next-rowid.md)
919923
- [`SHOW TABLE REGIONS`](/sql-statements/sql-statement-show-table-regions.md)
920924
- [`SHOW TABLE STATUS`](/sql-statements/sql-statement-show-table-status.md)
Lines changed: 46 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,46 @@
1+
---
2+
title: CANCEL DISTRIBUTION JOB
3+
summary: An overview of the usage of CANCEL DISTRIBUTION JOB in TiDB.
4+
---
5+
6+
# CANCEL DISTRIBUTION JOB <span class="version-mark">New in v9.0.0</span>
7+
8+
The `CANCEL DISTRIBUTION JOB` statement is used to cancel a Region scheduling task created using the [`DISTRIBUTE TABLE`](/sql-statements/sql-statement-distribute-table.md) statement in TiDB.
9+
10+
<CustomContent platform="tidb-cloud">
11+
12+
> **Note:**
13+
>
14+
> This feature is not available on [{{{ .starter }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#tidb-cloud-serverless) and [{{{ .essential }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#essential) clusters.
15+
16+
</CustomContent>
17+
18+
## Synopsis
19+
20+
```ebnf+diagram
21+
CancelDistributionJobsStmt ::=
22+
'CANCEL' 'DISTRIBUTION' 'JOB' JobID
23+
```
24+
25+
## Examples
26+
27+
The following example cancels the distribution job with ID `1`:
28+
29+
```sql
30+
CANCEL DISTRIBUTION JOB 1;
31+
```
32+
33+
The output is as follows:
34+
35+
```
36+
Query OK, 0 rows affected (0.01 sec)
37+
```
38+
39+
## MySQL compatibility
40+
41+
This statement is a TiDB extension to MySQL syntax.
42+
43+
## See also
44+
45+
* [`DISTRIBUTE TABLE`](/sql-statements/sql-statement-distribute-table.md)
46+
* [`SHOW DISTRIBUTION JOBS`](/sql-statements/sql-statement-show-distribution-jobs.md)
Lines changed: 128 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,128 @@
1+
---
2+
title: DISTRIBUTE TABLE
3+
summary: An overview of the usage of DISTRIBUTE TABLE for the TiDB database.
4+
---
5+
6+
# DISTRIBUTE TABLE <span class="version-mark">New in v9.0.0</span>
7+
8+
> **Warning:**
9+
>
10+
> This feature is experimental. It is not recommended that you use it in the production environment. This feature might be changed or removed without prior notice. If you find a bug, you can report an [issue](https://github.com/pingcap/tidb/issues) on GitHub.
11+
12+
<CustomContent platform="tidb-cloud">
13+
14+
> **Note:**
15+
>
16+
> This feature is not available on [{{{ .starter }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#tidb-cloud-serverless) and [{{{ .essential }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#essential) clusters.
17+
18+
</CustomContent>
19+
20+
The `DISTRIBUTE TABLE` statement redistributes and reschedules Regions of a specified table to achieve a balanced distribution at the table level. Executing this statement helps prevent Regions from being concentrated on a few TiFlash or TiKV nodes, addressing the issue of uneven region distribution in the table.
21+
22+
## Synopsis
23+
24+
```ebnf+diagram
25+
DistributeTableStmt ::=
26+
"DISTRIBUTE" "TABLE" TableName PartitionNameListOpt "RULE" EqOrAssignmentEq Identifier "ENGINE" EqOrAssignmentEq Identifier "TIMEOUT" EqOrAssignmentEq Identifier
27+
28+
TableName ::=
29+
(SchemaName ".")? Identifier
30+
31+
PartitionNameList ::=
32+
"PARTITION" "(" PartitionName ("," PartitionName)* ")"
33+
```
34+
35+
## Parameter description
36+
37+
When redistributing Regions in a table using the `DISTRIBUTE TABLE` statement, you can specify the storage engine (such as TiFlash or TiKV) and different Raft roles (such as Leader, Learner, or Voter) for balanced distribution.
38+
39+
- `RULE`: specifies which Raft role's Region to balance and schedule. Optional values are `"leader-scatter"`, `"peer-scatter"`, and `"learner-scatter"`.
40+
- `ENGINE`: specifies the storage engine. Optional values are `"tikv"` and `"tiflash"`.
41+
- `TIMEOUT`: specifies the timeout limit for the scatter operation. If PD does not complete the scatter within this time, the scatter task will automatically exit. When this parameter is not specified, the default value is `"30m"`.
42+
43+
## Examples
44+
45+
Redistribute the Regions of the Leaders in the table `t1` on TiKV:
46+
47+
```sql
48+
CREATE TABLE t1 (a INT);
49+
...
50+
DISTRIBUTE TABLE t1 RULE = "leader-scatter" ENGINE = "tikv" TIMEOUT = "1h";
51+
```
52+
53+
```
54+
+--------+
55+
| JOB_ID |
56+
+--------+
57+
| 100 |
58+
+--------+
59+
```
60+
61+
Redistribute the Regions of the Learners in the table `t2` on TiFlash:
62+
63+
```sql
64+
CREATE TABLE t2 (a INT);
65+
...
66+
DISTRIBUTE TABLE t2 RULE = "learner-scatter" ENGINE = "tiflash";
67+
```
68+
69+
```
70+
+--------+
71+
| JOB_ID |
72+
+--------+
73+
| 101 |
74+
+--------+
75+
```
76+
77+
Redistribute the Regions of the Peers in the table `t3`'s `p1` and `p2` partitions on TiKV:
78+
79+
```sql
80+
CREATE TABLE t3 ( a INT, b INT, INDEX idx(b)) PARTITION BY RANGE( a ) (
81+
PARTITION p1 VALUES LESS THAN (10000),
82+
PARTITION p2 VALUES LESS THAN (20000),
83+
PARTITION p3 VALUES LESS THAN (MAXVALUE) );
84+
...
85+
DISTRIBUTE TABLE t3 PARTITION (p1, p2) RULE = "peer-scatter" ENGINE = "tikv";
86+
```
87+
88+
```
89+
+--------+
90+
| JOB_ID |
91+
+--------+
92+
| 102 |
93+
+--------+
94+
```
95+
96+
Redistribute the Regions of the Learner in the table `t4`'s `p1` and `p2` partitions on TiFlash:
97+
98+
```sql
99+
CREATE TABLE t4 ( a INT, b INT, INDEX idx(b)) PARTITION BY RANGE( a ) (
100+
PARTITION p1 VALUES LESS THAN (10000),
101+
PARTITION p2 VALUES LESS THAN (20000),
102+
PARTITION p3 VALUES LESS THAN (MAXVALUE) );
103+
...
104+
DISTRIBUTE TABLE t4 PARTITION (p1, p2) RULE = "learner-scatter" ENGINE="tiflash";
105+
```
106+
107+
```
108+
+--------+
109+
| JOB_ID |
110+
+--------+
111+
| 103 |
112+
+--------+
113+
```
114+
115+
## Notes
116+
117+
When you execute the `DISTRIBUTE TABLE` statement to redistribute Regions of a table, the Region distribution result might be affected by the PD hotspot scheduler. After the redistribution, the Region distribution of this table might become imbalanced again over time.
118+
119+
## MySQL compatibility
120+
121+
This statement is a TiDB extension to MySQL syntax.
122+
123+
## See also
124+
125+
- [`SHOW DISTRIBUTION JOBS`](/sql-statements/sql-statement-show-distribution-jobs.md)
126+
- [`SHOW TABLE DISTRIBUTION`](/sql-statements/sql-statement-show-table-distribution.md)
127+
- [`SHOW TABLE REGIONS`](/sql-statements/sql-statement-show-table-regions.md)
128+
- [`CANCEL DISTRIBUTION JOB`](/sql-statements/sql-statement-cancel-distribution-job.md)
Lines changed: 51 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,51 @@
1+
---
2+
title: SHOW DISTRIBUTION JOBS
3+
summary: An overview of the usage of SHOW DISTRIBUTION JOBS for the TiDB database.
4+
---
5+
6+
# SHOW DISTRIBUTION JOBS <span class="version-mark">New in v9.0.0</span>
7+
8+
The `SHOW DISTRIBUTION JOBS` statement shows all current Region distribution jobs.
9+
10+
<CustomContent platform="tidb-cloud">
11+
12+
> **Note:**
13+
>
14+
> This feature is not available on [{{{ .starter }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#tidb-cloud-serverless) and [{{{ .essential }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#essential) clusters.
15+
16+
</CustomContent>
17+
18+
## Syntax
19+
20+
```ebnf+diagram
21+
ShowDistributionJobsStmt ::=
22+
"SHOW" "DISTRIBUTION" "JOBS"
23+
```
24+
25+
## Examples
26+
27+
Show all current Region distribution jobs:
28+
29+
```sql
30+
SHOW DISTRIBUTION JOBS;
31+
```
32+
33+
```
34+
+--------+----------+-------+----------------+--------+----------------+-----------+---------------------+---------------------+---------------------+
35+
| Job_ID | Database | Table | Partition_List | Engine | Rule | Status | Create_Time | Start_Time | Finish_Time |
36+
+--------+----------+-------+----------------+--------+----------------+-----------+---------------------+---------------------+---------------------+
37+
| 100 | test | t1 | NULL | tikv | leader-scatter | finished | 2025-04-24 16:09:55 | 2025-04-24 16:09:55 | 2025-04-24 17:09:59 |
38+
| 101 | test | t2 | NULL | tikv | learner-scatter| cancelled | 2025-05-08 15:33:29 | 2025-05-08 15:33:29 | 2025-05-08 15:33:37 |
39+
| 102 | test | t5 | p1,p2 | tikv | peer-scatter | cancelled | 2025-05-21 15:32:44 | 2025-05-21 15:32:47 | 2025-05-21 15:32:47 |
40+
+--------+----------+-------+----------------+--------+----------------+-----------+---------------------+---------------------+---------------------+
41+
```
42+
43+
## MySQL compatibility
44+
45+
This statement is a TiDB extension to MySQL syntax.
46+
47+
## See also
48+
49+
- [`DISTRIBUTE TABLE`](/sql-statements/sql-statement-distribute-table.md)
50+
- [`SHOW TABLE DISTRIBUTION`](/sql-statements/sql-statement-show-table-distribution.md)
51+
- [`CANCEL DISTRIBUTION JOB`](/sql-statements/sql-statement-cancel-distribution-job.md)
Lines changed: 69 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,69 @@
1+
---
2+
title: SHOW TABLE DISTRIBUTION
3+
summary: An overview of the usage of SHOW TABLE DISTRIBUTION for the TiDB database.
4+
---
5+
6+
# SHOW TABLE DISTRIBUTION <span class="version-mark">New in v9.0.0</span>
7+
8+
The `SHOW TABLE DISTRIBUTION` statement shows the Region distribution information for a specified table.
9+
10+
<CustomContent platform="tidb-cloud">
11+
12+
> **Note:**
13+
>
14+
> This feature is not available on [{{{ .starter }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#tidb-cloud-serverless) and [{{{ .essential }}}](https://docs.pingcap.com/tidbcloud/select-cluster-tier#essential) clusters.
15+
16+
</CustomContent>
17+
18+
## Synopsis
19+
20+
```ebnf+diagram
21+
ShowTableDistributionStmt ::=
22+
"SHOW" "TABLE" TableName "DISTRIBUTIONS"
23+
24+
TableName ::=
25+
(SchemaName ".")? Identifier
26+
```
27+
28+
## Examples
29+
30+
Show the Region distribution of the table `t1`:
31+
32+
```sql
33+
CREATE TABLE `t` (
34+
`a` int DEFAULT NULL,
35+
`b` int DEFAULT NULL,
36+
KEY `idx` (`b`)
37+
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin
38+
PARTITION BY RANGE (`a`)
39+
(PARTITION `p1` VALUES LESS THAN (10000),
40+
PARTITION `p2` VALUES LESS THAN (MAXVALUE)) |
41+
SHOW TABLE t1 DISTRIBUTIONS;
42+
```
43+
44+
```
45+
+----------------+----------+------------+---------------------+-------------------+--------------------+-------------------+--------------------+--------------------------+-------------------------+--------------------------+------------------------+-----------------------+------------------------+
46+
| PARTITION_NAME | STORE_ID | STORE_TYPE | REGION_LEADER_COUNT | REGION_PEER_COUNT | REGION_WRITE_BYTES | REGION_WRITE_KEYS | REGION_WRITE_QUERY | REGION_LEADER_READ_BYTES | REGION_LEADER_READ_KEYS | REGION_LEADER_READ_QUERY | REGION_PEER_READ_BYTES | REGION_PEER_READ_KEYS | REGION_PEER_READ_QUERY |
47+
+----------------+----------+------------+---------------------+-------------------+--------------------+-------------------+--------------------+--------------------------+-------------------------+--------------------------+------------------------+-----------------------+------------------------+
48+
| p1 | 1 | tikv | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
49+
| p1 | 15 | tikv | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
50+
| p1 | 4 | tikv | 1 | 1 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
51+
| p1 | 5 | tikv | 0 | 1 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
52+
| p1 | 6 | tikv | 0 | 1 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
53+
| p2 | 1 | tikv | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
54+
| p2 | 15 | tikv | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
55+
| p2 | 4 | tikv | 0 | 1 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
56+
| p2 | 5 | tikv | 1 | 1 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
57+
| p2 | 6 | tikv | 0 | 1 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 |
58+
+----------------+----------+------------+---------------------+-------------------+--------------------+-------------------+--------------------+--------------------------+-------------------------+--------------------------+------------------------+-----------------------+------------------------+
59+
```
60+
61+
## MySQL compatibility
62+
63+
This statement is a TiDB extension to MySQL syntax.
64+
65+
## See also
66+
67+
- [`DISTRIBUTE TABLE`](/sql-statements/sql-statement-distribute-table.md)
68+
- [`SHOW DISTRIBUTION JOBS`](/sql-statements/sql-statement-show-distribution-jobs.md)
69+
- [`CANCEL DISTRIBUTION JOB`](/sql-statements/sql-statement-cancel-distribution-job.md)

0 commit comments

Comments
 (0)