Skip to content

Commit 0bf47c1

Browse files
committed
refacor source by comment
1 parent 7001425 commit 0bf47c1

File tree

5 files changed

+100
-81
lines changed

5 files changed

+100
-81
lines changed

docs/doc/14-sql-commands/00-ddl/20-table/60-optimize-table.md

Lines changed: 2 additions & 78 deletions
Original file line numberDiff line numberDiff line change
@@ -8,7 +8,7 @@ The objective of optimizing a table in Databend is to compact or purge its histo
88
Databend's Time Travel feature relies on historical data. If you purge historical data from a table with the command `OPTIMIZE TABLE <your_table> PURGE` or `OPTIMIZE TABLE <your_table> ALL`, the table will not be eligible for time travel. The command removes all snapshots (except the most recent one) and their associated segments,block files and table statistic file.
99
:::
1010

11-
## What are Snapshot, Segment, Block and Table statistic file?
11+
## What are Snapshot, Segment, Block?
1212

1313
Snapshot, segment, and block are the concepts Databend uses for data storage. Databend uses them to construct a hierarchical structure for storing table data.
1414

@@ -20,8 +20,6 @@ A snapshot is a JSON file that does not save the table's data but indicate the s
2020

2121
A segment is a JSON file that organizes the storage blocks (at least 1, at most 1,000) where the data is stored. If you run [FUSE_SEGMENT](../../../15-sql-functions/111-system-functions/fuse_segment.md) against a snapshot with the snapshot ID, you can find which segments are referenced by the snapshot.
2222

23-
A table statistic file is a JSON file that save table statistic data, such as distinct values of table column.
24-
2523
Databends saves actual table data in parquet files and considers each parquet file as a block. If you run [FUSE_BLOCK](../../../15-sql-functions/111-system-functions/fuse_block.md) against a snapshot with the snapshot ID, you can find which blocks are referenced by the snapshot.
2624

2725
Databend creates a unique ID for each database and table for storing the snapshot, segment, and block files and saves them to your object storage in the path `<bucket_name>/[root]/<db_id>/<table_id>/`. Each snapshot, segment, and block file is named with a UUID (32-character lowercase hexadecimal string).
@@ -31,7 +29,6 @@ Databend creates a unique ID for each database and table for storing the snapsho
3129
| Snapshot | JSON | `<32bitUUID>_<version>.json` | `<bucket_name>/[root]/<db_id>/<table_id>/_ss/` |
3230
| Segment | JSON | `<32bitUUID>_<version>.json` | `<bucket_name>/[root]/<db_id>/<table_id>/_sg/` |
3331
| Block | parquet | `<32bitUUID>_<version>.parquet` | `<bucket_name>/[root]/<db_id>/<table_id>/_b/` |
34-
| Table statistic | JSON | `<32bitUUID>_<version>.json` | `<bucket_name>/[root]/<db_id>/<table_id>/_ts/` |
3532

3633
## Table Optimization Considerations
3734

@@ -68,12 +65,12 @@ Optimizing a table could be time-consuming, especially for large ones. Databend
6865

6966
```sql
7067
OPTIMIZE TABLE [database.]table_name [ PURGE | COMPACT | ALL | [SEGMENT] [LIMIT <segment_count>]
71-
ANALYZE TABLE [database.]table_name
7268
```
7369

7470
- `OPTIMIZE TABLE <table_name> PURGE`
7571

7672
Purges the historical data of table. Only the latest snapshot (including the segments, blocks and table statistic file referenced by this snapshot) will be kept.
73+
(For more explanations of table statistic file, see [ANALYZE TABLE](./80-analyze-table.md).)
7774

7875
- `OPTIMIZE TABLE <table_name> COMPACT [LIMIT <segment_count>]`
7976

@@ -98,13 +95,6 @@ ANALYZE TABLE [database.]table_name
9895

9996
Works the same way as `OPTIMIZE TABLE <table_name> PURGE`.
10097

101-
- `ANALYZE TABLE <table_name>`
102-
103-
Estimates the number of distinct values of each column in a table.
104-
105-
- It does not display the estimated results after execution. To show the estimated results, use the function [FUSE_STATISTIC](../../../15-sql-functions/111-system-functions/fuse_statistic.md).
106-
- The command does not identify distinct values by comparing them but by counting the number of storage segments and blocks. This might lead to a significant difference between the estimated results and the actual value, for example, multiple blocks holding the same value. In this case, Databend recommends compacting the storage segments and blocks to merge them as much as possible before you run the estimation.
107-
10898
## Examples
10999

110100
This example compacts and purges historical data from a table:
@@ -163,70 +153,4 @@ mysql> select snapshot_id, segment_count, block_count, row_count from fuse_snaps
163153
+----------------------------------+---------------+-------------+-----------+
164154
| 4f33a63031424ed095b8c2f9e8b15ecb | 16 | 16 | 10000005 |
165155
+----------------------------------+---------------+-------------+-----------+
166-
```
167-
168-
This example estimates the number of distinct values for each column in a table and shows the results with the function FUSE_STATISTIC:
169-
170-
```sql
171-
create table t(a uint64);
172-
173-
insert into t values (5);
174-
insert into t values (6);
175-
insert into t values (7);
176-
177-
select * from t order by a;
178-
179-
----
180-
5
181-
6
182-
7
183-
184-
-- FUSE_STATISTIC will not return any results until you run an estimation with OPTIMIZE TABLE.
185-
select * from fuse_statistic('db_09_0020', 't');
186-
187-
analyze table `t`;
188-
189-
select * from fuse_statistic('db_09_0020', 't');
190-
191-
----
192-
(0,3);
193-
194-
195-
insert into t values (5);
196-
insert into t values (6);
197-
insert into t values (7);
198-
199-
select * from t order by a;
200-
201-
----
202-
5
203-
5
204-
6
205-
6
206-
7
207-
7
208-
209-
-- FUSE_STATISTIC returns results of your last estimation. To get the most recent estimated values, run the estimation again.
210-
-- OPTIMIZE TABLE does not identify distinct values by comparing them but by counting the number of storage segments and blocks.
211-
select * from fuse_statistic('db_09_0020', 't');
212-
213-
----
214-
(0,3);
215-
216-
analyze table `t`;
217-
218-
select * from fuse_statistic('db_09_0020', 't');
219-
220-
----
221-
(0,6);
222-
223-
-- Best practice: Compact the table before running the estimation.
224-
optimize table t compact;
225-
226-
analyze table `t`;
227-
228-
select * from fuse_statistic('db_09_0020', 't');
229-
230-
----
231-
(0,3);
232156
```
Lines changed: 95 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,95 @@
1+
---
2+
title: ANALYZE TABLE
3+
---
4+
5+
The objective of analyzing a table in Databend is to calculate table statistics, such as distinct number of columns.
6+
7+
## What is Table statistic file?
8+
9+
A table statistic file is a JSON file that save table statistic data, such as distinct values of table column.
10+
11+
Databend creates a unique ID for each database and table for storing the table statistic file and saves them to your object storage in the path `<bucket_name>/[root]/<db_id>/<table_id>/`. Each table statistic file is named with a UUID (32-character lowercase hexadecimal string).
12+
13+
| File | Format | Filename | Storage Folder |
14+
|----------|---------|---------------------------------|----------------------------------------------------------------------------|
15+
| Table statistic | JSON | `<32bitUUID>_<version>.json` | `<bucket_name>/[root]/<db_id>/<table_id>/_ts/` |
16+
17+
## Syntax
18+
```sql
19+
ANALYZE TABLE [database.]table_name
20+
```
21+
22+
- `ANALYZE TABLE <table_name>`
23+
24+
Estimates the number of distinct values of each column in a table.
25+
26+
- It does not display the estimated results after execution. To show the estimated results, use the function [FUSE_STATISTIC](../../../15-sql-functions/111-system-functions/fuse_statistic.md).
27+
- The command does not identify distinct values by comparing them but by counting the number of storage segments and blocks. This might lead to a significant difference between the estimated results and the actual value, for example, multiple blocks holding the same value. In this case, Databend recommends compacting the storage segments and blocks to merge them as much as possible before you run the estimation.
28+
29+
## Examples
30+
31+
This example estimates the number of distinct values for each column in a table and shows the results with the function FUSE_STATISTIC:
32+
33+
```sql
34+
create table t(a uint64);
35+
36+
insert into t values (5);
37+
insert into t values (6);
38+
insert into t values (7);
39+
40+
select * from t order by a;
41+
42+
----
43+
5
44+
6
45+
7
46+
47+
-- FUSE_STATISTIC will not return any results until you run an estimation with OPTIMIZE TABLE.
48+
select * from fuse_statistic('db_09_0020', 't');
49+
50+
analyze table `t`;
51+
52+
select * from fuse_statistic('db_09_0020', 't');
53+
54+
----
55+
(0,3);
56+
57+
58+
insert into t values (5);
59+
insert into t values (6);
60+
insert into t values (7);
61+
62+
select * from t order by a;
63+
64+
----
65+
5
66+
5
67+
6
68+
6
69+
7
70+
7
71+
72+
-- FUSE_STATISTIC returns results of your last estimation. To get the most recent estimated values, run the estimation again.
73+
-- OPTIMIZE TABLE does not identify distinct values by comparing them but by counting the number of storage segments and blocks.
74+
select * from fuse_statistic('db_09_0020', 't');
75+
76+
----
77+
(0,3);
78+
79+
analyze table `t`;
80+
81+
select * from fuse_statistic('db_09_0020', 't');
82+
83+
----
84+
(0,6);
85+
86+
-- Best practice: Compact the table before running the estimation.
87+
optimize table t compact;
88+
89+
analyze table `t`;
90+
91+
select * from fuse_statistic('db_09_0020', 't');
92+
93+
----
94+
(0,3);
95+
```

src/query/ast/src/parser/token.rs

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -837,7 +837,7 @@ impl TokenKind {
837837
match self {
838838
| TokenKind::ALL
839839
// | TokenKind::ANALYSE
840-
// | TokenKind::ANALYZE
840+
| TokenKind::ANALYZE
841841
| TokenKind::AND
842842
// | TokenKind::ANY
843843
| TokenKind::ASC
@@ -982,7 +982,7 @@ impl TokenKind {
982982
match self {
983983
| TokenKind::ALL
984984
// | TokenKind::ANALYSE
985-
// | TokenKind::ANALYZE
985+
| TokenKind::ANALYZE
986986
| TokenKind::AND
987987
| TokenKind::ANY
988988
| TokenKind::ASC

src/query/service/tests/it/storages/fuse/operations/mod.rs

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -21,4 +21,4 @@ mod optimize;
2121
mod purge_drop;
2222
mod purge_truncate;
2323
mod read_plan;
24-
mod table_statistics;
24+
mod table_analyze;

0 commit comments

Comments
 (0)