Skip to content

Commit

Permalink
Added COALESCE PARTITION (#13162)
Browse files Browse the repository at this point in the history
  • Loading branch information
mjonss committed Apr 25, 2023
1 parent 08b7b1e commit 769dbb0
Show file tree
Hide file tree
Showing 3 changed files with 90 additions and 17 deletions.
8 changes: 8 additions & 0 deletions glossary.md
Expand Up @@ -40,6 +40,10 @@ A [Region](#regionpeerraft-group) is logically divided into several small ranges

With the cached table feature, TiDB loads the data of an entire table into the memory of the TiDB server, and TiDB directly gets the table data from the memory without accessing TiKV, which improves the read performance.

### Coalesce Partition

Coalesce Partition is a way of decreasing the number of partitions in a Hash or Key partitioned table. For more information, see [Manage Hash and Key partitions](/partitioned-table.md#manage-hash-and-key-partitions).

### Continuous Profiling

Introduced in TiDB 5.3.0, Continuous Profiling is a way to observe resource overhead at the system call level. With the support of Continuous Profiling, TiDB provides performance insight as clear as directly looking into the database source code, and helps R&D and operation and maintenance personnel to locate the root cause of performance problems using a flame graph. For details, see [TiDB Dashboard Instance Profiling - Continuous Profiling](/dashboard/continuous-profiling.md).
Expand Down Expand Up @@ -93,6 +97,10 @@ Currently, available steps generated by PD include:

## P

### Partitioning

[Partitioning](/partitioned-table.md) refers to physically dividing a table into smaller table partitions, which can be done by partition methods such as RANGE, LIST, HASH, and KEY partitioning.

### pending/down

"Pending" and "down" are two special states of a peer. Pending indicates that the Raft log of followers or learners is vastly different from that of leader. Followers in pending cannot be elected as leader. "Down" refers to a state that a peer ceases to respond to leader for a long time, which usually means the corresponding node is down or isolated from the network.
Expand Down
6 changes: 4 additions & 2 deletions mysql-compatibility.md
Expand Up @@ -158,10 +158,12 @@ In TiDB, all supported DDL changes are performed online. Compared with DDL opera
* Adding/Dropping the primary key of the `CLUSTERED` type is unsupported. For more details about the primary key of the `CLUSTERED` type, refer to [clustered index](/clustered-indexes.md).
* Different types of indexes (`HASH|BTREE|RTREE|FULLTEXT`) are not supported, and will be parsed and ignored when specified.
* TiDB supports `HASH`, `RANGE`, `LIST`, and `KEY` partitioning types. Currently, the `KEY` partition type does not support partition statements with an empty partition column list. For an unsupported partition type, TiDB returns `Warning: Unsupported partition type %s, treat as normal table`, where `%s` is the specific unsupported partition type.
* Partitioned tables support `ADD`, `DROP`, `TRUNCATE`, and `REORGANIZE` operations. Other partition operations are ignored. The following syntaxes are not supported for partitioned tables:
* Range, Range COLUMNS, List, and List COLUMNS partitioned tables support `ADD`, `DROP`, `TRUNCATE`, and `REORGANIZE` operations. Other partition operations are ignored.
* Hash and Key partitioned tables support `ADD`, `COALESCE`, and `TRUNCATE` operations. Other partition operations are ignored.
* The following syntaxes are not supported for partitioned tables:

- `SUBPARTITION`
- `{CHECK|TRUNCATE|OPTIMIZE|REPAIR|IMPORT|DISCARD|REBUILD|COALESCE} PARTITION`
- `{CHECK|OPTIMIZE|REPAIR|IMPORT|DISCARD|REBUILD} PARTITION`

For more details, see [Partitioning](/partitioned-table.md).

Expand Down
93 changes: 78 additions & 15 deletions partitioned-table.md
Expand Up @@ -816,7 +816,11 @@ For `RANGE`, `RANGE COLUMNS`, `LIST`, and `LIST COLUMNS` partitioned tables, you
- Remove all data from specified partitions using the `ALTER TABLE <table name> TRUNCATE PARTITION <list of partitions>` statement. The logic of `TRUNCATE PARTITION` is similar to [`TRUNCATE TABLE`](/sql-statements/sql-statement-truncate.md) but it is for partitions.
- Merge, split, or make other changes to the partitions using the `ALTER TABLE <table name> REORGANIZE PARTITION <list of partitions> INTO (<new partition definitions>)` statement.

For `HASH` and `KEY` partitioned tables, only `ALTER TABLE ... TRUNCATE PARTITION` is supported, while `COALESCE PARTITION` and `ADD PARTITION` are not yet supported.
For `HASH` and `KEY` partitioned tables, you can manage the partitions as follows:

- Decrease the number of partitions using the `ALTER TABLE <table name> COALESCE PARTITION <number of partitions to decrease by>` statement. This operation reorganizes the partitions by copying the whole table to the new number of partitions online.
- Increase the number of partitions using the `ALTER TABLE <table name> ADD PARTITION <number of partitions to increase by | (additional partition definitions)>` statement. This operation reorganizes the partitions by copying the whole table to the new number of partitions online.
- Remove all data from specified partitions using the `ALTER TABLE <table name> TRUNCATE PARTITION <list of partitions>` statement. The logic of `TRUNCATE PARTITION` is similar to [`TRUNCATE TABLE`](/sql-statements/sql-statement-truncate.md) but it is for partitions.

`EXCHANGE PARTITION` works by swapping a partition and a non-partitioned table, similar to how renaming a table like `RENAME TABLE t1 TO t1_tmp, t2 TO t1, t1_tmp TO t2` works.

Expand Down Expand Up @@ -983,42 +987,101 @@ When reorganizing partitions, you need to note the following key points:
ERROR 1526 (HY000): Table has no partition for value 6
```

### Manage Hash partitions
- After partitions are reorganized, the statistics of the corresponding partitions are outdated, so you will get the following warning. In this case, you can use the [`ANALYZE TABLE`](/sql-statements/sql-statement-analyze-table.md) statement to update the statistics.

Unlike Range partitioning, `DROP PARTITION` is not supported in Hash partitioning.
```sql
+---------+------+--------------------------------------------------------------------------------------------------------------------------------------------------------+
| Level | Code | Message |
+---------+------+--------------------------------------------------------------------------------------------------------------------------------------------------------+
| Warning | 1105 | The statistics of related partitions will be outdated after reorganizing partitions. Please use 'ANALYZE TABLE' statement if you want to update it now |
+---------+------+--------------------------------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.00 sec)
```

Currently, `ALTER TABLE ... COALESCE PARTITION` is not supported in TiDB as well. For partition management statements that are not currently supported, TiDB returns an error.
### Manage Hash and Key partitions

{{< copyable "sql" >}}
This section uses the partitioned table created by the following SQL statement as examples to show you how to manage Hash partitions. For Key partitions, you can use the same management statements as well.

```sql
CREATE TABLE example (
id INT PRIMARY KEY,
data VARCHAR(1024)
)
PARTITION BY HASH(id)
PARTITIONS 2;
```

#### Increase the number of partitions

Increase the number of partitions for the `example` table by 1 (from 2 to 3):

```sql
ALTER TABLE example ADD PARTITION PARTITIONS 1;
```

You can also specify partition options by adding partition definitions. For example, you can use the following statement to increase the number of partitions from 3 to 5 and specify the names of the newly added partitions as `pExample4` and `pExample5`:

```sql
ALTER TABLE MEMBERS OPTIMIZE PARTITION p0;
ALTER TABLE example ADD PARTITION
(PARTITION pExample4 COMMENT = 'not p3, but pExample4 instead',
PARTITION pExample5 COMMENT = 'not p4, but pExample5 instead');
```

#### Decrease the number of partitions

Unlike Range and List partitioning, `DROP PARTITION` is not supported for Hash and Key partitioning, but you can decrease the number of partitions with `COALESCE PARTITION` or delete all data from specific partitions with `TRUNCATE PARTITION`.

Decrease the number of partitions for the `example` table by 1 (from 5 to 4):

```sql
ERROR 8200 (HY000): Unsupported optimize partition
ALTER TABLE example COALESCE PARTITION 1;
```

### Key partition management
> **Notes:**
>
> The process of changing the number of partitions for Hash or Key partitioned tables reorganizes the partitions by copying all data to the new number of partitions. Therefore, after changing the number of partitions for a Hash or Key partitioned table, you will get the following warning about the outdated statistics. In this case, you can use the [`ANALYZE TABLE`](/sql-statements/sql-statement-analyze-table.md) statement to update the statistics.
>
> ```sql
> +---------+------+--------------------------------------------------------------------------------------------------------------------------------------------------------+
> | Level | Code | Message |
> +---------+------+--------------------------------------------------------------------------------------------------------------------------------------------------------+
> | Warning | 1105 | The statistics of related partitions will be outdated after reorganizing partitions. Please use 'ANALYZE TABLE' statement if you want to update it now |
> +---------+------+--------------------------------------------------------------------------------------------------------------------------------------------------------+
> 1 row in set (0.00 sec)
> ```
Currently, Key partitioning only supports the `ALTER TABLE ... TRUNCATE PARTITION` partition management statement.
To better understand how the `example` table is organized now, you can show the SQL statement that is used to recreate the `example` table as follows:

```sql
ALTER TABLE members TRUNCATE PARTITION p0;
SHOW CREATE TABLE\G
```

```
Query OK, 0 rows affected (0.03 sec)
*************************** 1. row ***************************
Table: example
Create Table: CREATE TABLE `example` (
`id` int(11) NOT NULL,
`data` varchar(1024) DEFAULT NULL,
PRIMARY KEY (`id`) /*T![clustered_index] CLUSTERED */
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin
PARTITION BY HASH (`id`)
(PARTITION `p0`,
PARTITION `p1`,
PARTITION `p2`,
PARTITION `pExample4` COMMENT 'not p3, but pExample4 instead')
1 row in set (0.01 sec)
```

If you execute a Key partition management statement that is not yet supported, TiDB returns an error.
#### Truncate partitions

Delete all data from a partition:

```sql
ALTER TABLE members OPTIMIZE PARTITION p0;
ALTER TABLE example TRUNCATE PARTITION p0;
```

```sql
ERROR 8200 (HY000): Unsupported optimize partition
```
Query OK, 0 rows affected (0.03 sec)
```

## Partition pruning
Expand Down

0 comments on commit 769dbb0

Please sign in to comment.