From bc0fb25a960064fc4a00e7096e4c89f8ce8fa8be Mon Sep 17 00:00:00 2001 From: Null not nil <67764674+nullnotnil@users.noreply.github.com> Date: Wed, 22 Jul 2020 21:49:03 -0600 Subject: [PATCH] sql-statements: add SHOW STATS_HEALTHY (#3388) * sql-statements: ADD SHOW STATS_HEALTHY * Update sql-statements/sql-statement-show-stats-healthy.md Co-authored-by: Keke Yi <40977455+yikeke@users.noreply.github.com> * Update sql-statements/sql-statement-show-stats-healthy.md Co-authored-by: Keke Yi <40977455+yikeke@users.noreply.github.com> Co-authored-by: Keke Yi <40977455+yikeke@users.noreply.github.com> Co-authored-by: ti-srebot <66930949+ti-srebot@users.noreply.github.com> --- TOC.md | 1 + .../sql-statement-show-stats-healthy.md | 89 +++++++++++++++++++ 2 files changed, 90 insertions(+) create mode 100644 sql-statements/sql-statement-show-stats-healthy.md diff --git a/TOC.md b/TOC.md index aab3c062a19c8..07c7c847eef4b 100644 --- a/TOC.md +++ b/TOC.md @@ -325,6 +325,7 @@ + [`SHOW PROFILES`](/sql-statements/sql-statement-show-profiles.md) + [`SHOW PUMP STATUS`](/sql-statements/sql-statement-show-pump-status.md) + [`SHOW SCHEMAS`](/sql-statements/sql-statement-show-schemas.md) + + [`SHOW STATS_HEALTHY`](/sql-statements/sql-statement-show-stats-healthy.md) + [`SHOW STATS_HISTOGRAMS`](/sql-statements/sql-statement-show-histograms.md) + [`SHOW STATES_META`](/sql-statements/sql-statement-show-stats-meta.md) + [`SHOW STATUS`](/sql-statements/sql-statement-show-status.md) diff --git a/sql-statements/sql-statement-show-stats-healthy.md b/sql-statements/sql-statement-show-stats-healthy.md new file mode 100644 index 0000000000000..22e214cf61497 --- /dev/null +++ b/sql-statements/sql-statement-show-stats-healthy.md @@ -0,0 +1,89 @@ +--- +title: SHOW STATS_HEALTHY +summary: An overview of the usage of SHOW STATS_HEALTHY for TiDB database. +--- + +# SHOW STATS_HEALTHY + +The `SHOW STATS_HEALTHY` statement shows an estimation of how accurate statistics are believed to be. Tables with a low percentage health may generate sub-optimal query execution plans. + +The health of a table can be improved by running the `ANALYZE` table command. `ANALYZE` runs automatically when the health drops below the [`tidb_auto_analyze_ratio`](/system-variables.md#tidb_auto_analyze_ratio) threshold. + +## Synopsis + +**ShowStmt** + +![ShowStmt](/media/sqlgram/ShowStmt.png) + +**ShowTargetFiltertable** + +![ShowTargetFilterable](/media/sqlgram/ShowTargetFilterable.png) + +**ShowLikeOrWhereOpt** + +![ShowLikeOrWhereOpt](/media/sqlgram/ShowLikeOrWhereOpt.png) + +## Examples + +Load example data and run `ANALYZE`: + +{{< copyable "sql" >}} + +```sql +CREATE TABLE t1 ( + id INT NOT NULL PRIMARY KEY auto_increment, + b INT NOT NULL, + pad VARBINARY(255), + INDEX(b) +); + +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM dual; +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; +INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000; +SELECT SLEEP(1); +ANALYZE TABLE t1; +SHOW STATS_HEALTHY; # should be 100% healthy +``` + +```sql +... +mysql> SHOW STATS_HEALTHY; ++---------+------------+----------------+---------+ +| Db_name | Table_name | Partition_name | Healthy | ++---------+------------+----------------+---------+ +| test | t1 | | 100 | ++---------+------------+----------------+---------+ +1 row in set (0.00 sec) +``` + +Perform a bulk update deleting approximately 30% of the records. Check the health of the statistics: + +{{< copyable "sql" >}} + +```sql +DELETE FROM t1 WHERE id BETWEEN 101010 AND 201010; # delete about 30% of records +SHOW STATS_HEALTHY; +``` + +```sql +mysql> SHOW STATS_HEALTHY; ++---------+------------+----------------+---------+ +| Db_name | Table_name | Partition_name | Healthy | ++---------+------------+----------------+---------+ +| test | t1 | | 50 | ++---------+------------+----------------+---------+ +1 row in set (0.00 sec) +``` + +## MySQL compatibility + +This statement is a TiDB extension to MySQL syntax. + +## See also + +* [ANALYZE](/sql-statements/sql-statement-analyze-table.md) +* [Introduction to Statistics](/statistics.md)