Skip to content

Commit

Permalink
update doc about show analyze status #9497 (#8774) (#8826)
Browse files Browse the repository at this point in the history
  • Loading branch information
ti-chi-bot authored Jun 8, 2022
1 parent d1e924e commit b955325
Show file tree
Hide file tree
Showing 4 changed files with 92 additions and 58 deletions.
48 changes: 30 additions & 18 deletions information-schema/information-schema-analyze-status.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,54 +7,66 @@ summary: Learn the `ANALYZE_STATUS` information_schema table.

The `ANALYZE_STATUS` table provides information about the running tasks that collect statistics and a limited number of history tasks.

Starting from TiDB v6.1.0, the `ANALYZE_STATUS` table supports showing cluster-level tasks. Even after a TiDB restart, you can still view task records before the restart using this table. Before TiDB v6.1.0, the `ANALYZE_STATUS` table can only show instance-level tasks, and task records are cleared after a TiDB restart.

Starting from TiDB v6.1.0, you can view the history tasks within the last 7 days through the system table `mysql.analyze_jobs`.

{{< copyable "sql" >}}

```sql
USE information_schema;
DESC analyze_status;
```

```
```sql
+----------------+---------------------+------+------+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+----------------+---------------------+------+------+---------+-------+
| TABLE_SCHEMA | varchar(64) | YES | | NULL | |
| TABLE_NAME | varchar(64) | YES | | NULL | |
| PARTITION_NAME | varchar(64) | YES | | NULL | |
| JOB_INFO | varchar(64) | YES | | NULL | |
| PROCESSED_ROWS | bigint(20) unsigned | YES | | NULL | |
| JOB_INFO | longtext | YES | | NULL | |
| PROCESSED_ROWS | bigint(64) unsigned | YES | | NULL | |
| START_TIME | datetime | YES | | NULL | |
| END_TIME | datetime | YES | | NULL | |
| STATE | varchar(64) | YES | | NULL | |
| FAIL_REASON | longtext | YES | | NULL | |
| INSTANCE | varchar(512) | YES | | NULL | |
| PROCESS_ID | bigint(64) unsigned | YES | | NULL | |
+----------------+---------------------+------+------+---------+-------+
7 rows in set (0.00 sec)
11 rows in set (0.00 sec)
```

{{< copyable "sql" >}}

```sql
SELECT * FROM `ANALYZE_STATUS`;
SELECT * FROM information_schema.analyze_status;
```

```
+--------------+------------+----------------+-------------------+----------------+---------------------+----------+
| TABLE_SCHEMA | TABLE_NAME | PARTITION_NAME | JOB_INFO | PROCESSED_ROWS | START_TIME | STATE |
+--------------+------------+----------------+-------------------+----------------+---------------------+----------+
| test | t | | analyze index idx | 2 | 2019-06-21 19:51:14 | finished |
| test | t | | analyze columns | 2 | 2019-06-21 19:51:14 | finished |
| test | t1 | p0 | analyze columns | 0 | 2019-06-21 19:51:15 | finished |
| test | t1 | p3 | analyze columns | 0 | 2019-06-21 19:51:15 | finished |
| test | t1 | p1 | analyze columns | 0 | 2019-06-21 19:51:15 | finished |
| test | t1 | p2 | analyze columns | 1 | 2019-06-21 19:51:15 | finished |
+--------------+------------+----------------+-------------------+----------------+---------------------+----------+
6 rows in set
```sql
+--------------+------------+----------------+--------------------------------------------------------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
| TABLE_SCHEMA | TABLE_NAME | PARTITION_NAME | JOB_INFO | PROCESSED_ROWS | START_TIME | END_TIME | STATE | FAIL_REASON | INSTANCE | PROCESS_ID |
+--------------+------------+----------------+--------------------------------------------------------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
| test | t | p1 | analyze table all columns with 256 buckets, 500 topn, 1 samplerate | 0 | 2022-05-27 11:30:12 | 2022-05-27 11:30:12 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze table all columns with 256 buckets, 500 topn, 1 samplerate | 0 | 2022-05-27 11:30:12 | 2022-05-27 11:30:12 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p1 | analyze index idx | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze index idx | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p1 | analyze columns | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze columns | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
+--------------+------------+----------------+--------------------------------------------------------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
6 rows in set (0.00 sec)
```

Fields in the `ANALYZE_STATUS` table are described as follows:

* `TABLE_SCHEMA`: The name of the database to which the table belongs.
* `TABLE_NAME`: The name of the table.
* `PARTITION_NAME`: The name of the partitioned table.
* `JOB_INFO`: The information of the `ANALYZE` task.
* `JOB_INFO`: The information of the `ANALYZE` task. If an index is analyzed, this information will include the index name. When `tidb_analyze_version =2`, this information will include configuration items such as sample rate.
* `PROCESSED_ROWS`: The number of rows that have been processed.
* `START_TIME`: The start time of the `ANALYZE` task.
* `END_TIME`: The end time of the `ANALYZE` task.
* `STATE`: The execution status of the `ANALYZE` task. Its value can be `pending`, `running`,`finished` or `failed`.
* `FAIL_REASON`: The reason why the task fails. If the execution is successful, the value is `NULL`.
* `INSTANCE`: The TiDB instance that executes the task.
* `PROCESS_ID`: The process ID that executes the task.
1 change: 1 addition & 0 deletions mysql-schema.md
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,7 @@ Currently, the `help_topic` is NULL.
- `stats_buckets`: the buckets of statistics
- `stats_histograms`: the histograms of statistics
- `stats_meta`: the meta information of tables, such as the total number of rows and updated rows
- `analyze_jobs`: the ongoing statistics collection tasks and the history task records within the last 7 days

## GC worker system tables

Expand Down
67 changes: 44 additions & 23 deletions sql-statements/sql-statement-show-analyze-status.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,40 +7,61 @@ summary: An overview of the usage of SHOW ANALYZE STATUS for the TiDB database.

The `SHOW ANALYZE STATUS` statement shows the statistics collection tasks being executed by TiDB and a limited number of historical task records.

## Synopsis
Starting from TiDB v6.1.0, the `SHOW ANALYZE STATUS` statement supports showing cluster-level tasks. Even after a TiDB restart, you can still view task records before the restart using this statement. Before TiDB v6.1.0, the `SHOW ANALYZE STATUS` statement can only show instance-level tasks, and task records are cleared after a TiDB restart.

**ShowStmt:**
Starting from TiDB v6.1.0, you can view the history tasks within the last 7 days through the system table `mysql.analyze_jobs`.

![ShowStmt](/media/sqlgram/ShowStmt.png)
## Synopsis

**ShowTargetFilterable:**
```ebnf+diagram
ShowAnalyzeStatusStmt ::= 'SHOW' 'ANALYZE' 'STATUS' ShowLikeOrWhereOpt
![ShowTargetFilterable](/media/sqlgram/ShowTargetFilterable.png)
ShowLikeOrWhereOpt ::= 'LIKE' SimpleExpr | 'WHERE' Expression
```

## Examples

{{< copyable "sql" >}}

```sql
create table t(x int, index idx(x)) partition by hash(x) partition 4;
analyze table t;
show analyze status;
```
mysql> create table t(x int, index idx(x)) partition by hash(x) partitions 2;
Query OK, 0 rows affected (0.69 sec)

```sql
+--------------+------------+----------------+-------------------+----------------+---------------------+----------+
| Table_schema | Table_name | Partition_name | Job_info | Processed_rows | Start_time | State |
+--------------+------------+----------------+-------------------+----------------+---------------------+----------+
| test | t | p1 | analyze columns | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p0 | analyze columns | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p0 | analyze index idx | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p1 | analyze index idx | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p2 | analyze index idx | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p3 | analyze index idx | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p3 | analyze columns | 0 | 2020-05-25 17:23:55 | finished |
| test | t | p2 | analyze columns | 0 | 2020-05-25 17:23:55 | finished |
+--------------+------------+----------------+-------------------+----------------+---------------------+----------+
8 rows in set (0.00 sec)
mysql> set @@tidb_analyze_version = 1;
Query OK, 0 rows affected (0.00 sec)

mysql> analyze table t;
Query OK, 0 rows affected (0.20 sec)

mysql> show analyze status;
+--------------+------------+----------------+-------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
| Table_schema | Table_name | Partition_name | Job_info | Processed_rows | Start_time | End_time | State | Fail_reason | Instance | Process_ID |
+--------------+------------+----------------+-------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
| test | t | p1 | analyze index idx | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze index idx | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p1 | analyze columns | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze columns | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
+--------------+------------+----------------+-------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
4 rows in set (0.01 sec)

mysql> set @@tidb_analyze_version = 2;
Query OK, 0 rows affected (0.00 sec)

mysql> analyze table t;
Query OK, 0 rows affected, 2 warnings (0.03 sec)

mysql> show analyze status;
+--------------+------------+----------------+--------------------------------------------------------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
| Table_schema | Table_name | Partition_name | Job_info | Processed_rows | Start_time | End_time | State | Fail_reason | Instance | Process_ID |
+--------------+------------+----------------+--------------------------------------------------------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
| test | t | p1 | analyze table all columns with 256 buckets, 500 topn, 1 samplerate | 0 | 2022-05-27 11:30:12 | 2022-05-27 11:30:12 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze table all columns with 256 buckets, 500 topn, 1 samplerate | 0 | 2022-05-27 11:30:12 | 2022-05-27 11:30:12 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p1 | analyze index idx | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze index idx | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p1 | analyze columns | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
| test | t | p0 | analyze columns | 0 | 2022-05-27 11:29:46 | 2022-05-27 11:29:46 | finished | NULL | 127.0.0.1:4000 | NULL |
+--------------+------------+----------------+--------------------------------------------------------------------+----------------+---------------------+---------------------+----------+-------------+----------------+------------+
6 rows in set (0.00 sec)
```

## MySQL compatibility
Expand Down
34 changes: 17 additions & 17 deletions statistics.md
Original file line number Diff line number Diff line change
Expand Up @@ -334,29 +334,22 @@ Before TiDB v5.0, when you execute a query, TiDB collects feedback with `feedbac
Since TiDB v6.0, TiDB supports using the `KILL` statement to terminate an `ANALYZE` task running in the background. If you find that an `ANALYZE` task running in the background consumes a lot of resources and affects your application, you can terminate the `ANALYZE` task by taking the following steps:
1. Execute the following SQL statement to get the TiDB instance address and the `ID` of the background `ANALYZE` task:
1. Execute the following SQL statement:
{{< copyable "sql" >}}
```sql
SELECT ci.instance as instance, cp.id as id FROM information_schema.cluster_info ci, information_schema.cluster_processlist cp WHERE ci.status_address = cp.instance and ci.type = 'tidb' and cp.info like 'analyze table %' and cp.user = '' and cp.host = '';
SHOW ANALYZE STATUS
```
If there is no result, no `ANALYZE` task is running in the background.
By checking the `instance` column and the `process_id` column in the result, you can get the TiDB instance address and the task `ID` of the background `ANALYZE` task.
2. Use a client to connect to the TiDB instance where the background `ANALYZE` task is running, and then execute the following `KILL` statement:
2. Terminate the `ANALYZE` task that is running in the background.
{{< copyable "sql" >}}
- If [`enable-global-kill`](/tidb-configuration-file.md#enable-global-kill-new-in-v610) is `true` (`true` by default), you can execute the `KILL TIDB ${id};` statement directly, where `${id}` is the `ID` of the background `ANALYZE` task obtained from the previous step.
- If `enable-global-kill` is `false`, you need to use a client to connect to the TiDB instance that is executing the backend `ANALYZE` task, and then execute the `KILL TIDB ${id};` statement. If you use a client to connect to another TiDB instance, or if there is a proxy between the client and the TiDB cluster, the `KILL` statement cannot terminate the background `ANALYZE` task.
```sql
KILL TIDB ${id};
```
`${id}` is the `ID` of the background `ANALYZE` task obtained in the previous step.
> **Note:**
>
> The above `KILL` statement only works on a TiDB instance that is executing a background `ANALYZE` task. Therefore, you must use a client to connect to that TiDB instance first. If you use a client to connect to another TiDB instance, or if there is a proxy between the client and TiDB, the `KILL` statement cannot terminate the background `ANALYZE` task. For more information, see [`KILL [TIDB]`](/sql-statements/sql-statement-kill.md).
For more information on the `KILL` statement, see [`KILL`](/sql-statements/sql-statement-kill.md).
### Control `ANALYZE` concurrency
Expand Down Expand Up @@ -417,17 +410,24 @@ SHOW ANALYZE STATUS [ShowLikeOrWhere]
This statement returns the state of `ANALYZE`. You can use `ShowLikeOrWhere` to filter the information you need.
Currently, the `SHOW ANALYZE STATUS` statement returns the following 7 columns:
Currently, the `SHOW ANALYZE STATUS` statement returns the following 11 columns:
| Column name | Description |
| :-------- | :------------- |
| table_schema | The database name |
| table_name | The table name |
| partition_name| The partition name |
| job_info | The task information. The element includes index names when index analysis is performed. |
| row_count | The number of rows that have been analyzed |
| job_info | The task information. If an index is analyzed, this information will include the index name. When `tidb_analyze_version =2`, this information will include configuration items such as sample rate. |
| processed_rows | The number of rows that have been analyzed |
| start_time | The time at which the task starts |
| state | The state of a task, including `pending`, `running`, `finished`, and `failed` |
| fail_reason | The reason why the task fails. If the execution is successful, the value is `NULL`. |
| instance | The TiDB instance that executes the task |
| process_id | The process ID that executes the task |
Starting from TiDB v6.1.0, the `SHOW ANALYZE STATUS` statement supports showing cluster-level tasks. Even after a TiDB restart, you can still view task records before the restart using this statement. Before TiDB v6.1.0, the `SHOW ANALYZE STATUS` statement can only show instance-level tasks, and task records are cleared after a TiDB restart.
`SHOW ANALYZE STATUS` shows the most recent task records only. Starting from TiDB v6.1.0, you can view the history tasks within the last 7 days through the system table `mysql.analyze_jobs`.
## View statistics
Expand Down

0 comments on commit b955325

Please sign in to comment.