Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add observability for ALTER TABLE ... COMPACT #11684

Merged
merged 3 commits into from
Dec 23, 2022
Merged
Changes from 1 commit
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
101 changes: 99 additions & 2 deletions sql-statements/sql-statement-alter-table-compact.md
Original file line number Diff line number Diff line change
Expand Up @@ -89,11 +89,108 @@ To obtain greater table-level concurrency with higher resource usage, you can mo

</CustomContent>

## MySQL compatibility
## Observe data compaction progress

You can observe the progress of data compaction or determine whether to initiate compaction for a table by checking the `TOTAL_DELTA_ROWS` column in the `INFORMATION_SCHEMA.TIFLASH_TABLES` table. The larger the value of `TOTAL_DELTA_ROWS`, the more data that can be compacted. If `TOTAL_DELTA_ROWS` is `0`, all data in the table is in the best state and does not need to be compacted.

<details>
<summary>Example: Check the compaction state of a common table</summary>
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved

```sql
USE test;
CREATE TABLE foo(id INT);
ALTER TABLE foo SET TIFLASH REPLICA 1;
SELECT TOTAL_DELTA_ROWS, TOTAL_STABLE_ROWS FROM INFORMATION_SCHEMA.TIFLASH_TABLES
WHERE IS_TOMBSTONE = 0 AND
`TIDB_DATABASE` = "test" AND `TIDB_TABLE` = "foo";
+------------------+-------------------+
| TOTAL_DELTA_ROWS | TOTAL_STABLE_ROWS |
+------------------+-------------------+
| 0 | 0 |
+------------------+-------------------+
INSERT INTO foo VALUES (1), (3), (7);
SELECT TOTAL_DELTA_ROWS, TOTAL_STABLE_ROWS FROM INFORMATION_SCHEMA.TIFLASH_TABLES
WHERE IS_TOMBSTONE = 0 AND
`TIDB_DATABASE` = "test" AND `TIDB_TABLE` = "foo";
+------------------+-------------------+
| TOTAL_DELTA_ROWS | TOTAL_STABLE_ROWS |
+------------------+-------------------+
| 3 | 0 |
+------------------+-------------------+
-- Newly written data can be compacted
ALTER TABLE foo COMPACT TIFLASH REPLICA;
SELECT TOTAL_DELTA_ROWS, TOTAL_STABLE_ROWS FROM INFORMATION_SCHEMA.TIFLASH_TABLES
WHERE IS_TOMBSTONE = 0 AND
`TIDB_DATABASE` = "test" AND `TIDB_TABLE` = "foo";
+------------------+-------------------+
| TOTAL_DELTA_ROWS | TOTAL_STABLE_ROWS |
+------------------+-------------------+
| 0 | 3 |
+------------------+-------------------+
-- All data is in the best state and no compaction is required
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved
```

</details>

<details>
<summary>Example: Check the compaction state of partitioned tables</summary>
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved

```sql
USE test;
CREATE TABLE employees
(id INT NOT NULL, store_id INT)
PARTITION BY LIST (store_id) (
PARTITION pNorth VALUES IN (1, 2, 3, 4, 5),
PARTITION pEast VALUES IN (6, 7, 8, 9, 10),
PARTITION pWest VALUES IN (11, 12, 13, 14, 15),
PARTITION pCentral VALUES IN (16, 17, 18, 19, 20)
);
ALTER TABLE employees SET TIFLASH REPLICA 1;
INSERT INTO employees VALUES (1, 1), (6, 6), (10, 10);
SELECT PARTITION_NAME, TOTAL_DELTA_ROWS, TOTAL_STABLE_ROWS
FROM INFORMATION_SCHEMA.TIFLASH_TABLES t, INFORMATION_SCHEMA.PARTITIONS p
WHERE t.IS_TOMBSTONE = 0 AND t.TABLE_ID = p.TIDB_PARTITION_ID AND
p.TABLE_SCHEMA = "test" AND p.TABLE_NAME = "employees";
+----------------+------------------+-------------------+
| PARTITION_NAME | TOTAL_DELTA_ROWS | TOTAL_STABLE_ROWS |
+----------------+------------------+-------------------+
| pNorth | 1 | 0 |
| pEast | 2 | 0 |
| pWest | 0 | 0 |
| pCentral | 0 | 0 |
+----------------+------------------+-------------------+
-- Some partitioned tables can be compacted
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved
ALTER TABLE employees COMPACT TIFLASH REPLICA;
SELECT PARTITION_NAME, TOTAL_DELTA_ROWS, TOTAL_STABLE_ROWS
FROM INFORMATION_SCHEMA.TIFLASH_TABLES t, INFORMATION_SCHEMA.PARTITIONS p
WHERE t.IS_TOMBSTONE = 0 AND t.TABLE_ID = p.TIDB_PARTITION_ID AND
p.TABLE_SCHEMA = "test" AND p.TABLE_NAME = "employees";
+----------------+------------------+-------------------+
| PARTITION_NAME | TOTAL_DELTA_ROWS | TOTAL_STABLE_ROWS |
+----------------+------------------+-------------------+
| pNorth | 0 | 1 |
| pEast | 0 | 2 |
| pWest | 0 | 0 |
| pCentral | 0 | 0 |
+----------------+------------------+-------------------+
-- Data in al partitions is in the best state and no compaction is required
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved
```

</details>

> **Note:**
>
> - If data is updated during compaction, `TOTAL_DELTA_ROWS` might still be a non-zero value after compaction is done. This is normal and indicates that these updates have not been compacted. To compact these updates, execute the `ALTER TABLE ... COMPACT` statement again.
>
> - `TOTAL_DELTA_ROWS` indicates the number of data versions, not the number of rows. For example, if you insert a row and then delete it, `TOTAL_DELTA_ROWS` will increase by 2.
shichun-0415 marked this conversation as resolved.
Show resolved Hide resolved

## Compatibility

### MySQL compatibility

The `ALTER TABLE ... COMPACT` syntax is TiDB specific, which is an extension to the standard SQL syntax. Although there is no equivalent MySQL syntax, you can still execute this statement by using MySQL clients or various database drivers that comply with the MySQL protocol.

## TiDB Binlog and TiCDC compatibility
### TiDB Binlog and TiCDC compatibility

The `ALTER TABLE ... COMPACT` statement does not result in logical data changes and are therefore not replicated to downstream by TiDB Binlog or TiCDC.

Expand Down