Skip to content

Commit

Permalink
docs: add documentation for ADMIN ALTER DDL JOBS command (#19492)
Browse files Browse the repository at this point in the history
  • Loading branch information
tangenta authored Dec 2, 2024
1 parent 22341b8 commit 9184833
Show file tree
Hide file tree
Showing 3 changed files with 126 additions and 29 deletions.
1 change: 1 addition & 0 deletions TOC.md
Original file line number Diff line number Diff line change
Expand Up @@ -730,6 +730,7 @@
- SQL Statements
- [Overview](/sql-statements/sql-statement-overview.md)
- [`ADMIN`](/sql-statements/sql-statement-admin.md)
- [`ADMIN ALTER DDL JOBS`](/sql-statements/sql-statement-admin-alter-ddl.md)
- [`ADMIN CANCEL DDL`](/sql-statements/sql-statement-admin-cancel-ddl.md)
- [`ADMIN CHECKSUM TABLE`](/sql-statements/sql-statement-admin-checksum-table.md)
- [`ADMIN CHECK [TABLE|INDEX]`](/sql-statements/sql-statement-admin-check-table-index.md)
Expand Down
88 changes: 88 additions & 0 deletions sql-statements/sql-statement-admin-alter-ddl.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,88 @@
---
title: ADMIN ALTER DDL JOBS
summary: An overview of the usage of `ADMIN ALTER DDL JOBS` for the TiDB database.
---

# ADMIN ALTER DDL JOBS

The `ADMIN ALTER DDL JOBS` statement allows you to modify the parameter of a single running DDL job. For example:

```sql
ADMIN ALTER DDL JOBS 101 THREAD = 8;
```

- `101`: indicates the ID of the DDL job. You can obtain the ID by executing [`ADMIN SHOW DDL JOBS`](/sql-statements/sql-statement-admin-show-ddl.md).
- `THREAD`: indicates the concurrency of the DDL job. You can configure its initial value using the system variable [`tidb_ddl_reorg_worker_cnt`](/system-variables.md#tidb_ddl_reorg_worker_cnt).

The DDL job types supported by the `ADMIN ALTER DDL JOBS` statement include `ADD INDEX`, `MODIFY COLUMN`, and `REORGANIZE PARTITION`. For other DDL job types, executing `ADMIN ALTER DDL JOBS` returns the `unsupported DDL operation` error.

Currently, you can only modify the parameters of a single DDL job by executing `ADMIN ALTER DDL JOBS`. Modifying the parameters of multiple DDL job IDs at the same time is not supported.

The following are the supported parameters for different DDL jobs and their corresponding system variables:

- `ADD INDEX`:
- `THREAD`: the concurrency of the DDL job. The initial value is set by `tidb_ddl_reorg_worker_cnt`.
- `BATCH_SIZE`: the batch size. The initial value is set by [`tidb_ddl_reorg_batch_size`](/system-variables.md#tidb_ddl_reorg_batch_size).
- `MAX_WRITE_SPEED`: the maximum bandwidth limit for importing index records into each TiKV. The initial value is set by [`tidb_ddl_reorg_max_write_speed`](/system-variables.md#tidb_ddl_reorg_max_write_speed-new-in-v850).

Currently, the preceding parameters only work for `ADD INDEX` jobs that are submitted and running after [`tidb_enable_dist_task`](/system-variables.md#tidb_enable_dist_task-new-in-v710) is disabled.

- `MODIFY COLUMN`:
- `THREAD`: the concurrency of the DDL job. The initial value is set by `tidb_ddl_reorg_worker_cnt`.
- `BATCH_SIZE`: the batch size. The initial value is set by `tidb_ddl_reorg_batch_size`.

- `REORGANIZE PARTITION`:
- `THREAD`: the concurrency of the DDL job. The initial value is set by `tidb_ddl_reorg_worker_cnt`.
- `BATCH_SIZE`: the batch size. The initial value is set by `tidb_ddl_reorg_batch_size`.

The value ranges of the preceding parameters are consistent with those of the corresponding system variables.

`ADMIN ALTER DDL JOBS` takes effect only on running DDL jobs. If the DDL job does not exist or has already completed, executing this statement returns the `ddl job is not running` error.

The following are some examples of this statement:

```sql
ADMIN ALTER DDL JOBS 101 THREAD = 8;
ADMIN ALTER DDL JOBS 101 BATCH_SIZE = 256;
ADMIN ALTER DDL JOBS 101 MAX_WRITE_SPEED = '200MiB';
ADMIN ALTER DDL JOBS 101 THREAD = 8, BATCH_SIZE = 256;
```

To view the current parameter values for a specific DDL job, you can execute `ADMIN SHOW DDL JOBS`. The results are displayed in the `COMMENTS` column:

```sql
ADMIN SHOW DDL JOBS 1;
```

```
+--------+---------+------------+-----------+--------------+-----------+----------+-----------+----------------------------+----------------------------+----------------------------+--------+-----------------------+
| JOB_ID | DB_NAME | TABLE_NAME | JOB_TYPE | SCHEMA_STATE | SCHEMA_ID | TABLE_ID | ROW_COUNT | CREATE_TIME | START_TIME | END_TIME | STATE | COMMENTS |
+--------+---------+------------+-----------+--------------+-----------+----------+-----------+----------------------------+----------------------------+----------------------------+--------+-----------------------+
| 124 | test | t | add index | public | 2 | 122 | 3 | 2024-11-15 11:17:06.213000 | 2024-11-15 11:17:06.213000 | 2024-11-15 11:17:08.363000 | synced | ingest, DXF, thread=8 |
+--------+---------+------------+-----------+--------------+-----------+----------+-----------+----------------------------+----------------------------+----------------------------+--------+-----------------------+
1 row in set (0.01 sec)
```

## Synopsis

```ebnf+diagram
AdminAlterDDLStmt ::=
'ADMIN' 'ALTER' 'DDL' 'JOBS' Int64Num AlterJobOptionList
AlterJobOptionList ::=
AlterJobOption ( ',' AlterJobOption )*
AlterJobOption ::=
identifier "=" SignedLiteral
```

## MySQL compatibility

This statement is a TiDB extension to MySQL syntax.

## See also

* [`ADMIN SHOW DDL [JOBS|QUERIES]`](/sql-statements/sql-statement-admin-show-ddl.md)
* [`ADMIN CANCEL DDL`](/sql-statements/sql-statement-admin-cancel-ddl.md)
* [`ADMIN PAUSE DDL`](/sql-statements/sql-statement-admin-pause-ddl.md)
* [`ADMIN RESUME DDL`](/sql-statements/sql-statement-admin-resume-ddl.md)
66 changes: 37 additions & 29 deletions sql-statements/sql-statement-admin-show-ddl.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,9 +12,9 @@ The `ADMIN SHOW DDL [JOBS|JOB QUERIES]` statement shows information about runnin
```ebnf+diagram
AdminShowDDLStmt ::=
'ADMIN' 'SHOW' 'DDL'
(
'JOBS' Int64Num? WhereClauseOptional
| 'JOB' 'QUERIES' NumList
(
'JOBS' Int64Num? WhereClauseOptional
| 'JOB' 'QUERIES' NumList
| 'JOB' 'QUERIES' 'LIMIT' m ( ('OFFSET' | ',') n )?
)?
Expand Down Expand Up @@ -47,15 +47,15 @@ ADMIN SHOW DDL\G;
SCHEMA_VER: 26
OWNER_ID: 2d1982af-fa63-43ad-a3d5-73710683cc63
OWNER_ADDRESS: 0.0.0.0:4000
RUNNING_JOBS:
RUNNING_JOBS:
SELF_ID: 2d1982af-fa63-43ad-a3d5-73710683cc63
QUERY:
QUERY:
1 row in set (0.00 sec)
```

### `ADMIN SHOW DDL JOBS`

The `ADMIN SHOW DDL JOBS` statement is used to view all the results in the current DDL job queue, including running and queuing tasks, as well as the latest ten results in the completed DDL job queue. The returned result fields are described as follows:
The `ADMIN SHOW DDL JOBS` statement is used to view the 10 jobs in the current DDL job queue, including running and pending jobs (if any), and the last 10 jobs in the executed DDL job queue (if any). The returned result fields are described as follows:

<CustomContent platform="tidb">

Expand All @@ -66,9 +66,7 @@ The `ADMIN SHOW DDL JOBS` statement is used to view all the results in the curre
- `create schema`: for [`CREATE SCHEMA`](/sql-statements/sql-statement-create-database.md) operations.
- `create table`: for [`CREATE TABLE`](/sql-statements/sql-statement-create-table.md) operations.
- `create view`: for [`CREATE VIEW`](/sql-statements/sql-statement-create-view.md) operations.
- `ingest`: ingestion with accelerated index backfilling as configured by [`tidb_ddl_enable_fast_reorg`](/system-variables.md#tidb_ddl_enable_fast_reorg-new-in-v630).
- `txn`: basic transactional backfilling.
- `add index /* txn-merge */`: transactional backfilling with a temporary index that gets merged with the original index when the backfilling is finished.
- `add index`: for [`ADD INDEX`](/sql-statements/sql-statement-add-index.md) operations.
- `SCHEMA_STATE`: the current state of the schema object that the DDL operates on. If `JOB_TYPE` is `ADD INDEX`, it is the state of the index; if `JOB_TYPE` is `ADD COLUMN`, it is the state of the column; if `JOB_TYPE` is `CREATE TABLE`, it is the state of the table. Common states include the following:
- `none`: indicates that it does not exist. Generally, after the `DROP` operation or after the `CREATE` operation fails and rolls back, it will become the `none` state.
- `delete only`, `write only`, `delete reorganization`, `write reorganization`: these four states are intermediate states. For their specific meanings, see [How the Online DDL Asynchronous Change Works in TiDB](/ddl-introduction.md#how-the-online-ddl-asynchronous-change-works-in-tidb). As the intermediate state conversion is fast, these states are generally not visible during operation. Only when performing `ADD INDEX` operation can the `write reorganization` state be seen, indicating that index data is being added.
Expand All @@ -91,6 +89,15 @@ The `ADMIN SHOW DDL JOBS` statement is used to view all the results in the curre
- `pausing`: indicates that the operation is being paused.
- `paused`: indicates that the operation has been paused. This state only appears when you use the [`ADMIN PAUSED DDL JOBS`](/sql-statements/sql-statement-admin-pause-ddl.md) command to pause the DDL job. You can use the [`ADMIN RESUME DDL JOBS`](/sql-statements/sql-statement-admin-resume-ddl.md) command to resume the DDL job.
- `done`: indicates that the operation has been successfully executed on the TiDB owner node, but other TiDB nodes have not yet synchronized the changes performed by this DDL job.
- `COMMENTS`: contains additional information for diagnostic purposes.
- `ingest`: ingest tasks for accelerated adding index backfill configured via [`tidb_ddl_enable_fast_reorg`](/system-variables.md#tidb_ddl_enable_fast_reorg-new-in-v630)
- `txn`: transaction-based index backfill after [`tidb_ddl_enable_fast_reorg`](/system-variables.md#tidb_ddl_enable_fast_reorg-new-in-v630) is disabled.
- `txn-merge`: transactional backfilling with a temporary index that gets merged with the original index when the backfilling is finished.
- `DXF`: tasks executed with Distributed eXecution Framework (DXF) configured via [`tidb_enable_dist_task`](/system-variables.md#tidb_enable_dist_task-new-in-v710).
- `service_scope`: the service scope of the TiDB node configured via [`tidb_service_scope`](/system-variables.md#tidb_service_scope-new-in-v740).
- `thread`: the concurrency of backfill tasks. You can set the initial value by `tidb_ddl_reorg_worker_cnt`. It supports dynamic modification via [`ADMIN ALTER DDL JOBS`](/sql-statements/sql-statement-admin-alter-ddl.md).
- `batch_size`: the batch size of backfill tasks. You can set the initial value by `tidb_ddl_reorg_batch_size`. It supports dynamic modification via `ADMIN ALTER DDL JOBS`.
- `max_write_speed`: flow control during ingest task import. The initial value can be set with `tidb_ddl_reorg_max_write_speed`. It supports dynamic modification via `ADMIN ALTER DDL JOBS`.

</CustomContent>

Expand Down Expand Up @@ -126,31 +133,32 @@ ADMIN SHOW DDL JOBS;
```

```sql
mysql> ADMIN SHOW DDL JOBS;
+--------+---------+--------------------+--------------+----------------------+-----------+----------+-----------+-----------------------------------------------------------------+---------+
| JOB_ID | DB_NAME | TABLE_NAME | JOB_TYPE | SCHEMA_STATE | SCHEMA_ID | TABLE_ID | ROW_COUNT | CREATE_TIME | START_TIME | END_TIME | STATE |
+--------+---------+--------------------+--------------+----------------------+-----------+----------+-----------+---------------------+-------------------------------------------+---------+
| 59 | test | t1 | add index | write reorganization | 1 | 55 | 88576 | 2020-08-17 07:51:58 | 2020-08-17 07:51:58 | NULL | running |
| 60 | test | t2 | add index | none | 1 | 57 | 0 | 2020-08-17 07:51:59 | 2020-08-17 07:51:59 | NULL | none |
| 58 | test | t2 | create table | public | 1 | 57 | 0 | 2020-08-17 07:41:28 | 2020-08-17 07:41:28 | 2020-08-17 07:41:28 | synced |
| 56 | test | t1 | create table | public | 1 | 55 | 0 | 2020-08-17 07:41:02 | 2020-08-17 07:41:02 | 2020-08-17 07:41:02 | synced |
| 54 | test | t1 | drop table | none | 1 | 50 | 0 | 2020-08-17 07:41:02 | 2020-08-17 07:41:02 | 2020-08-17 07:41:02 | synced |
| 53 | test | t1 | drop index | none | 1 | 50 | 0 | 2020-08-17 07:35:44 | 2020-08-17 07:35:44 | 2020-08-17 07:35:44 | synced |
| 52 | test | t1 | add index | public | 1 | 50 | 451010 | 2020-08-17 07:34:43 | 2020-08-17 07:34:43 | 2020-08-17 07:35:16 | synced |
| 51 | test | t1 | create table | public | 1 | 50 | 0 | 2020-08-17 07:34:02 | 2020-08-17 07:34:02 | 2020-08-17 07:34:02 | synced |
| 49 | test | t1 | drop table | none | 1 | 47 | 0 | 2020-08-17 07:34:02 | 2020-08-17 07:34:02 | 2020-08-17 07:34:02 | synced |
| 48 | test | t1 | create table | public | 1 | 47 | 0 | 2020-08-17 07:33:37 | 2020-08-17 07:33:37 | 2020-08-17 07:33:37 | synced |
| 46 | mysql | stats_extended | create table | public | 3 | 45 | 0 | 2020-08-17 06:42:38 | 2020-08-17 06:42:38 | 2020-08-17 06:42:38 | synced |
| 44 | mysql | opt_rule_blacklist | create table | public | 3 | 43 | 0 | 2020-08-17 06:42:38 | 2020-08-17 06:42:38 | 2020-08-17 06:42:38 | synced |
+--------+---------+--------------------+--------------+----------------------+-----------+----------+-----------+---------------------+---------------------+-------------------------------+
12 rows in set (0.00 sec)
+--------+---------+------------+---------------------------------+----------------------+-----------+----------+-----------+----------------------------+----------------------------+----------------------------+----------+-------------+
| JOB_ID | DB_NAME | TABLE_NAME | JOB_TYPE | SCHEMA_STATE | SCHEMA_ID | TABLE_ID | ROW_COUNT | CREATE_TIME | START_TIME | END_TIME | STATE | COMMENTS |
+--------+---------+------------+---------------------------------+----------------------+-----------+----------+-----------+----------------------------+----------------------------+----------------------------+----------+-------------+
| 565 | test | sbtest1 | add index | write reorganization | 554 | 556 | 0 | 2024-11-22 12:39:25.475000 | 2024-11-22 12:39:25.524000 | NULL | running | ingest, DXF |
| 566 | test | sbtest1 | add index | none | 554 | 556 | 0 | 2024-11-22 12:39:26.425000 | NULL | NULL | queueing | |
| 564 | test | sbtest1 | alter table multi-schema change | none | 554 | 556 | 0 | 2024-11-22 12:39:02.925000 | 2024-11-22 12:39:02.925000 | 2024-11-22 12:39:03.275000 | synced | |
| 564 | test | sbtest1 | drop index /* subjob */ | none | 554 | 556 | 0 | 2024-11-22 12:39:02.925000 | 2024-11-22 12:39:02.925000 | 2024-11-22 12:39:03.275000 | done | |
| 564 | test | sbtest1 | drop index /* subjob */ | none | 554 | 556 | 0 | 2024-11-22 12:39:02.925000 | 2024-11-22 12:39:02.975000 | 2024-11-22 12:39:03.275000 | done | |
| 563 | test | sbtest1 | modify column | public | 554 | 556 | 0 | 2024-11-22 12:38:35.624000 | 2024-11-22 12:38:35.624000 | 2024-11-22 12:38:35.674000 | synced | |
| 562 | test | sbtest1 | add index | public | 554 | 556 | 1580334 | 2024-11-22 12:36:58.471000 | 2024-11-22 12:37:05.271000 | 2024-11-22 12:37:13.374000 | synced | ingest, DXF |
| 561 | test | sbtest1 | add index | public | 554 | 556 | 1580334 | 2024-11-22 12:36:57.771000 | 2024-11-22 12:36:57.771000 | 2024-11-22 12:37:04.671000 | synced | ingest, DXF |
| 560 | test | sbtest1 | add index | public | 554 | 556 | 1580334 | 2024-11-22 12:34:53.314000 | 2024-11-22 12:34:53.314000 | 2024-11-22 12:34:57.114000 | synced | ingest |
| 559 | test | sbtest1 | drop index | none | 554 | 556 | 0 | 2024-11-22 12:34:43.565000 | 2024-11-22 12:34:43.565000 | 2024-11-22 12:34:43.764000 | synced | |
| 558 | test | sbtest1 | add index | public | 554 | 556 | 1580334 | 2024-11-22 12:34:06.215000 | 2024-11-22 12:34:06.215000 | 2024-11-22 12:34:14.314000 | synced | ingest, DXF |
| 557 | test | sbtest1 | create table | public | 554 | 556 | 0 | 2024-11-22 12:32:09.515000 | 2024-11-22 12:32:09.915000 | 2024-11-22 12:32:10.015000 | synced | |
| 555 | test | | create schema | public | 554 | 0 | 0 | 2024-11-22 12:31:51.215000 | 2024-11-22 12:31:51.264000 | 2024-11-22 12:31:51.264000 | synced | |
| 553 | test | | drop schema | none | 2 | 0 | 0 | 2024-11-22 12:31:48.615000 | 2024-11-22 12:31:48.615000 | 2024-11-22 12:31:48.865000 | synced | |
+--------+---------+------------+---------------------------------+----------------------+-----------+----------+-----------+----------------------------+----------------------------+----------------------------+----------+-------------+
14 rows in set (0.00 sec)
```

From the output above:

- Job 59 is currently in progress (`STATE` of `running`). The schema state is currently in `write reorganization`, but will switch to `public` once the task is completed to note that the change can be observed publicly by user sessions. The `end_time` column is also `NULL` indicating that the completion time for the job is currently not known.
- Job 565 is currently in progress (`STATE` of `running`). The schema state is currently in `write reorganization`, but will switch to `public` once the job is completed to note that the change can be observed publicly by user sessions. The `end_time` column is also `NULL` indicating that the completion time for the job is currently not known.

- Job 60 is an `add index` job, which is currently queued waiting for job 59 to complete. When job 59 completes, the `STATE` of job 60 will switch to `running`.
- The `STATE` for `job_id` 566 is shown as `queueing`, indicating that it is queuing. When job 565 completes and job 566 begins execution, the `STATE` for job 566 will change to `running`.

- For destructive changes such as dropping an index or dropping a table, the `SCHEMA_STATE` will change to `none` when the job is complete. For additive changes, the `SCHEMA_STATE` will change to `public`.

Expand Down

0 comments on commit 9184833

Please sign in to comment.