tencent cloud

Secondary Partition
Last updated: 2025-11-14 10:59:24
Secondary Partition
Last updated: 2025-11-14 10:59:24

Feature Description

In the MySQL database, partitioning is a technology that allows you to divide a table or index data into multiple logical sections, which can improve query efficiency and reduce maintenance costs. The secondary partition allows for a more fine-grained division of data, enabling the creation of multiple sub-partitions within a single partition, improving data management and query efficiency. TencentDB for MySQL supports the creation of secondary partitions of range or list type.

Supported Versions

MySQL 8.0 kernel version 20230630 and later versions.

Applicable Scenario

For more fine-grained data management and queries, the secondary partition can be used to improve query efficiency, such as partitioning a large table.

Must-Knows

A new syntax for the template, SUBPARTITION TEMPLATE, has been added, ensuring that each sub-partition is defined consistently.
The name format of each sub-partition is: first-level partition name $$ secondary partition name template.
The secondary partition does not support column_list.
It is not supported to truncate all partitions using "truncate ... with global index" currently. To truncate all partitions, you can run "truncate table".
In partitioned tables that contain global indexes, the process of performing the truncate partition operation is consistent with that of the official MySQL, and online DDL is not supported. However, when the truncate partition operation is performed for partitioned tables that contain global indexes, it is required to maintain global indexes, resulting in longer running times. It is recommended to use the delete syntax method instead of truncate.
The $$ character cannot exist in the secondary partition name template.
The drop partition operation requires the rebuilding of the global index. It is recommended to combine multiple drop partition statements into a single statement for execution to reduce the cost associated with maintaining the global index.
It is not recommended to perform operations by running truncate partition, which will block DML.

Use Instructions

1. Create a table with secondary partitions.
CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name
(create_definition,...)
[table_options]
[partition_options]

partition_options:
PARTITION BY
{ [LINEAR] HASH(expr)
| [LINEAR] KEY [ALGORITHM={1 | 2}] (column_list)
| RANGE{(expr) | COLUMNS(column_list)}
| LIST{(expr) | COLUMNS(column_list)} }
[PARTITIONS num]
[SUBPARTITION BY
{ [LINEAR] HASH(expr)
| [LINEAR] KEY [ALGORITHM={1 | 2}] (column_list) }
[SUBPARTITIONS num]
]
[SUBPARTITION BY
{ RANGE{(expr)} -- Range-type secondary partition template.
| LIST{(expr)} -- List-type secondary partition template.
SUBPARTITION TEMPLATE [(subpartition_definition [, subpartition_definition] ...)]} -- Sub-partition template.
]
[(partition_definition [, partition_definition] ...)]

subpartition_definition:
SUBPARTITION logical_name
[VALUES
{ LESS THAN {(expr | value_list) | MAXVALUE} --Range-type sub-partition range.
| IN (value_list)}] --List-type sub-partition range.
[[STORAGE] ENGINE [=] engine_name]
[COMMENT [=] 'string' ]
[DATA DIRECTORY [=] 'data_dir']
[INDEX DIRECTORY [=] 'index_dir']
[MAX_ROWS [=] max_number_of_rows]
[MIN_ROWS [=] min_number_of_rows]
[TABLESPACE [=] tablespace_name]
Example:
CREATE TABLE `t1` (
`id` int DEFAULT NULL,
`purchased` int DEFAULT NULL,
KEY `idx` (`id`,`purchased`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
/*!50100 PARTITION BY RANGE (`id`)
SUBPARTITION BY RANGE (`purchased`)
SUBPARTITION TEMPLATE
(SUBPARTITION s0 VALUES LESS THAN (10) ENGINE = InnoDB,
SUBPARTITION s1 VALUES LESS THAN (20) ENGINE = InnoDB)
(PARTITION p0 VALUES LESS THAN (10) ENGINE = InnoDB,
PARTITION p1 VALUES LESS THAN (20) ENGINE = InnoDB,
PARTITION p2 VALUES LESS THAN (30) ENGINE = InnoDB) */;
2. ALTER TABLE syntax.
-- Secondary partition DDL.
ALTER TABLE tbl_name
[alter_option [, alter_option] ...]
[partition_options] [subpartition_options] -- Add new subpartition_options.

subpartition_options:
subpartition_option [subpartition_option] ...

subpartition_options: {
MODIFY PARTITION partition_name TRUNCATE SUBPARTITION TEMPLATE subpartition_template_name; -- Truncate the partitions with the template named subpartition_template_nam in the partition_name.
| TRUNCATE SUBPARTITION TEMPLATE subpartition_template_name -- Truncate secondary partitions of the subpartition_template_name.
| ADD SUBPARTITION TEMPLATE subpartition_definitions -- Add a template for subpartition_definitions.
| DROP SUBPARTITION TEMPLATE subpartition_template_name -- Drop secondary partitions of subpartition_template_name.
}

-- First-level partition DDL.
ALTER TABLE t1 TRUNCATE p0 WITH GLOBAL INDEX; -- Truncate partition p1. (If sub-partitions exist, truncate all the following sub-partitions.)
Example:
-- Secondary partition DDL.
ALTER TABLE t1 MODIFY PARTITION p0 TRUNCATE SUBPARTITION TEMPLATE s1; -- Truncate secondary partition p0_s1 (first-level partition p0, secondary partition template name s1).
ALTER TABLE t1 TRUNCATE SUBPARTITION TEMPLATE s1; -- Sub-partitions with the suffix of _s1 under all partitions will be truncated.
ALTER TABLE t1 ADD SUBPARTITION TEMPLATE (SUBPARTITION s2 values in (1,2,3,4)); -- Sub-partitions with the suffix of _s2 will be added for all partitions.
ALTER TABLE t1 DROP SUBPARTITION TEMPLATE s2; -- Sub-partitions with the suffix of _s2 will be deleted for all partitions.

-- First-level partition DDL.
ALTER TABLE t1 ADD PARTITION (PARTITION p2 VALUES LESS THAN (20)); -- Add a partition. If t1 is a secondary partition table, the template will be used to generate sub-partitions by default.
ALTER TABLE t1 DROP PARTITION p1;
ALTER TABLE t1 TRUNCATE p0 WITH GLOBAL INDEX; -- Truncate partition p1. (If sub-partitions exist, truncate all the following sub-partitions.)
3. Support new time functions.
tdsql_year, tdsql_month, and tdsql_day will convert time to the formats of YYYY, YYYYMM, and YYYYMMDD. The supported types include DATE/DATETIME/TINYINT/SMALLINT/MEDIUMINT/BIGINT/CHAR/VARCHAR/VARBINARY/timestamp/binary.
When tdsql_year, tdsql_month, and tdsql_day are used as functions in the partition keys, the binary and timestamp types are not supported.
Was this page helpful?
You can also Contact Sales or Submit a Ticket for help.
Yes
No

Feedback