阅读range分区文档
This commit is contained in:
@@ -303,3 +303,108 @@ ALTER TABLE np_pk
|
|||||||
PARTITION BY HASH(id)
|
PARTITION BY HASH(id)
|
||||||
PARTITIONS 4;
|
PARTITIONS 4;
|
||||||
```
|
```
|
||||||
|
### 分区类型
|
||||||
|
#### RANGE
|
||||||
|
RANGE为较常见的分区类型,如下示例为创建RANGE类型分区表的示例:
|
||||||
|
```sql
|
||||||
|
create table t1 (
|
||||||
|
id bigint auto_increment not null,
|
||||||
|
tran_date datetime(6) not null default now(6) on update now(6),
|
||||||
|
primary key (id, tran_date)
|
||||||
|
) engine=innodb
|
||||||
|
partition by range (year(tran_date)) (
|
||||||
|
partition part_y_let_2024 values less than (2025),
|
||||||
|
partition part_y_eq_2025 values less than (2026)
|
||||||
|
);
|
||||||
|
```
|
||||||
|
上述创建了表`t1`,t1主键为`(id, tran_date)`,且按照`tran_date`字段的年部分进行分区,分区类型为RANGE。
|
||||||
|
|
||||||
|
表t1的分区为两部分,分区1为`tran_date位于2024或之前年份`的分区`part_y_let_2024`,分区2是`tran_date位于2025年`的分区`part_y_eq_2025`。
|
||||||
|
|
||||||
|
##### information_schema.partitions
|
||||||
|
如果要查看表的分区情况,可以查询`information_schema.partitions`表,示例如下
|
||||||
|
```sql
|
||||||
|
select * from information_schema.partitions where table_schema = 'learn_innodb' and table_name = 't1';
|
||||||
|
```
|
||||||
|
查询结果如下所示:
|
||||||
|
| TABLE\_CATALOG | TABLE\_SCHEMA | TABLE\_NAME | PARTITION\_NAME | SUBPARTITION\_NAME | PARTITION\_ORDINAL\_POSITION | SUBPARTITION\_ORDINAL\_POSITION | PARTITION\_METHOD | SUBPARTITION\_METHOD | PARTITION\_EXPRESSION | SUBPARTITION\_EXPRESSION | PARTITION\_DESCRIPTION | TABLE\_ROWS | AVG\_ROW\_LENGTH | DATA\_LENGTH | MAX\_DATA\_LENGTH | INDEX\_LENGTH | DATA\_FREE | CREATE\_TIME | UPDATE\_TIME | CHECK\_TIME | CHECKSUM | PARTITION\_COMMENT | NODEGROUP | TABLESPACE\_NAME |
|
||||||
|
| :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- |
|
||||||
|
| def | learn\_innodb | t1 | part\_y\_eq\_2025 | null | 2 | null | RANGE | null | year\(\`tran\_date\`\) | null | 2026 | 0 | 0 | 16384 | 0 | 0 | 0 | 2025-02-08 01:05:53 | null | null | null | | default | null |
|
||||||
|
| def | learn\_innodb | t1 | part\_y\_let\_2024 | null | 1 | null | RANGE | null | year\(\`tran\_date\`\) | null | 2025 | 0 | 0 | 16384 | 0 | 0 | 0 | 2025-02-08 01:05:53 | null | null | null | | default | null |
|
||||||
|
|
||||||
|
为分区表预置如下数据
|
||||||
|
```sql
|
||||||
|
insert into t1(tran_date) values ('2023-01-01'), ('2024-12-31'), ('2025-01-01');
|
||||||
|
```
|
||||||
|
可以看到分区表中数据分布如下:
|
||||||
|
```sql
|
||||||
|
select partition_name, table_rows from information_schema.partitions where table_schema = 'learn_innodb' and table_name = 't1';
|
||||||
|
```
|
||||||
|
| PARTITION\_NAME | TABLE\_ROWS |
|
||||||
|
| :--- | :--- |
|
||||||
|
| part\_y\_eq\_2025 | 1 |
|
||||||
|
| part\_y\_let\_2024 | 2 |
|
||||||
|
|
||||||
|
易知`('2023-01-01'), ('2024-12-31')`数据位于`part_y_let_2024`分区,故而该分区存在两条数据;而`('2025-01-01')`数据位于`part_y_let_2024`分区,该分区存在一条数据。
|
||||||
|
|
||||||
|
##### 看select语句查询了哪些分区
|
||||||
|
数据分布可以通过如下方式验证:
|
||||||
|
```sql
|
||||||
|
explain select * from t1 where tran_date >= '2023-01-01' and tran_date <= '2024-12-31';
|
||||||
|
```
|
||||||
|
| id | select\_type | table | partitions | type | possible\_keys | key | key\_len | ref | rows | filtered | Extra |
|
||||||
|
| :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- |
|
||||||
|
| 1 | SIMPLE | t1 | part\_y\_let\_2024 | index | PRIMARY | PRIMARY | 16 | null | 2 | 50 | Using where; Using index |
|
||||||
|
|
||||||
|
```sql
|
||||||
|
explain select * from t1 where tran_date >= '2025-01-01'
|
||||||
|
```
|
||||||
|
| id | select\_type | table | partitions | type | possible\_keys | key | key\_len | ref | rows | filtered | Extra |
|
||||||
|
| :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- | :--- |
|
||||||
|
| 1 | SIMPLE | t1 | part\_y\_eq\_2025 | index | PRIMARY | PRIMARY | 16 | null | 1 | 100 | Using where; Using index |
|
||||||
|
|
||||||
|
##### 插入超过分区范围的数据
|
||||||
|
如果尝试向分区表中插入超过所有分区范围的数据,会执行失败,示例如下:
|
||||||
|
```sql
|
||||||
|
insert into t1(tran_date) values ('2026-01-01');
|
||||||
|
```
|
||||||
|
由于分区表`t1`中现有分区最大只支持2025年的分区,故而当尝试插入2026年分区时,会抛出如下错误:
|
||||||
|
```bash
|
||||||
|
[2025-02-08 01:32:51] [HY000][1526] Table has no partition for value 2026
|
||||||
|
```
|
||||||
|
##### 向分区表中添加分区
|
||||||
|
mysql支持向分区表中添加分区,语法如下
|
||||||
|
```sql
|
||||||
|
alter table t1 add partition (
|
||||||
|
partition part_year_egt_2026 values less than maxvalue
|
||||||
|
);
|
||||||
|
```
|
||||||
|
添加分区后,mysql支持`tran_date大于等于2026`的分区,执行如下语句
|
||||||
|
```sql
|
||||||
|
insert into t1(tran_date) values ('2026-01-01'), ('2027-12-31'), ('2028-01-01');
|
||||||
|
```
|
||||||
|
之后,再次分区分区中的数据分区,结果如下
|
||||||
|
| PARTITION\_NAME | TABLE\_ROWS |
|
||||||
|
| :--- | :--- |
|
||||||
|
| part\_y\_eq\_2025 | 1 |
|
||||||
|
| part\_y\_let\_2024 | 2 |
|
||||||
|
| part\_year\_egt\_2026 | 3 |
|
||||||
|
|
||||||
|
> `information.partitions`表中,`table_rows`字段可能存在不准确的情况,如果想要获取准确的值,需要执行`analyze table {schema}.{table_name}`语句
|
||||||
|
|
||||||
|
##### 向分区表中删除分区
|
||||||
|
当想要删除分区表中现存分区时,可以通过执行如下语句
|
||||||
|
```sql
|
||||||
|
alter table t1 drop partition part_year_egt_2026;
|
||||||
|
```
|
||||||
|
在删除分区后,分区中的数据也会被删除,执行查询语句后
|
||||||
|
```sql
|
||||||
|
select * from t1;
|
||||||
|
|
||||||
|
```
|
||||||
|
可知`part_year_egt_2026`被删除后分区中数据全部消失
|
||||||
|
| id | tran\_date |
|
||||||
|
| :--- | :--- |
|
||||||
|
| 1 | 2023-01-01 00:00:00.000000 |
|
||||||
|
| 2 | 2024-12-31 00:00:00.000000 |
|
||||||
|
| 3 | 2025-01-01 00:00:00.000000 |
|
||||||
|
|||||||
Reference in New Issue
Block a user