MySQL :: MySQL 8.4 Reference Manual :: 26.3.4 Maintenance of Partitions (original) (raw)

26.3.4 Maintenance of Partitions

A number of table and partition maintenance tasks can be carried out on partitioned tables using SQL statements intended for such purposes.

Table maintenance of partitioned tables can be accomplished using the statements CHECK TABLE,OPTIMIZE TABLE,ANALYZE TABLE, andREPAIR TABLE, which are supported for partitioned tables.

You can use a number of extensions toALTER TABLE for performing operations of this type on one or more partitions directly, as described in the following list:

ALTER TABLE t1 REBUILD PARTITION p0, p1;  
ALTER TABLE t1 OPTIMIZE PARTITION p0, p1;  

Using OPTIMIZE PARTITION on a given partition is equivalent to running CHECK PARTITION, ANALYZE PARTITION, and REPAIR PARTITION on that partition.
Some MySQL storage engines, includingInnoDB, do not support per-partition optimization; in these cases,ALTER TABLE ... OPTIMIZE PARTITION analyzes and rebuilds the entire table, and causes an appropriate warning to be issued. (Bug #11751825, Bug #42822) Use ALTER TABLE ... REBUILD PARTITION and ALTER TABLE ... ANALYZE PARTITION instead, to avoid this issue.

ALTER TABLE t1 ANALYZE PARTITION p3;  
ALTER TABLE t1 REPAIR PARTITION p0,p1;  

Normally, REPAIR PARTITION fails when the partition contains duplicate key errors. You can useALTER IGNORE TABLE with this option, in which case all rows that cannot be moved due to the presence of duplicate keys are removed from the partition (Bug #16900947).

ALTER TABLE trb3 CHECK PARTITION p1;  

This statement tells you whether the data or indexes in partition p1 of tablet1 are corrupted. If this is the case, useALTER TABLE ... REPAIR PARTITION to repair the partition.
Normally, CHECK PARTITION fails when the partition contains duplicate key errors. You can useALTER IGNORE TABLE with this option, in which case the statement returns the contents of each row in the partition where a duplicate key violation is found. Only the values for the columns in the partitioning expression for the table are reported. (Bug #16900947)

Each of the statements in the list just shown also supports the keyword ALL in place of the list of partition names. Using ALL causes the statement to act on all partitions in the table.

You can also truncate partitions usingALTER TABLE ... TRUNCATE PARTITION. This statement can be used to delete all rows from one or more partitions in much the same way that TRUNCATE TABLE deletes all rows from a table.

ALTER TABLE ... TRUNCATE PARTITION ALL truncates all partitions in the table.