13.1.8.1 ALTER TABLE Partition Operations (original) (raw)

Simply using a partitionoptions clause with ALTER TABLE on a partitioned table repartitions the table according to the partitioning scheme defined by the_partitionoptions. This clause always begins with PARTITION BY, and follows the same syntax and other rules as apply to thepartitionoptions_ clause forCREATE TABLE (for more detailed information, see Section 13.1.18, “CREATE TABLE Statement”), and can also be used to partition an existing table that is not already partitioned. For example, consider a (nonpartitioned) table defined as shown here:

CREATE TABLE t1 (
    id INT,
    year_col INT
);

This table can be partitioned by HASH, using the id column as the partitioning key, into 8 partitions by means of this statement:

ALTER TABLE t1
    PARTITION BY HASH(id)
    PARTITIONS 8;

MySQL supports an ALGORITHM option with[SUB]PARTITION BY [LINEAR] KEY.ALGORITHM=1 causes the server to use the same key-hashing functions as MySQL 5.1 when computing the placement of rows in partitions;ALGORITHM=2 means that the server employs the key-hashing functions implemented and used by default for new KEY partitioned tables in MySQL 5.5 and later. (Partitioned tables created with the key-hashing functions employed in MySQL 5.5 and later cannot be used by a MySQL 5.1 server.) Not specifying the option has the same effect as using ALGORITHM=2. This option is intended for use chiefly when upgrading or downgrading [LINEAR] KEY partitioned tables between MySQL 5.1 and later MySQL versions, or for creating tables partitioned by KEY orLINEAR KEY on a MySQL 5.5 or later server which can be used on a MySQL 5.1 server.

To upgrade a KEY partitioned table that was created in MySQL 5.1, first executeSHOW CREATE TABLE and note the exact columns and number of partitions shown. Now execute an ALTER TABLE statement using exactly the same column list and number of partitions as in the CREATE TABLE statement, while addingALGORITHM=2 immediately following thePARTITION BY keywords. (You should also include the LINEAR keyword if it was used for the original table definition.) An example from a session in the mysql client is shown here:

mysql> SHOW CREATE TABLE p\G
*************************** 1. row ***************************
       Table: p
Create Table: CREATE TABLE `p` (
  `id` int(11) NOT NULL AUTO_INCREMENT,
  `cd` datetime NOT NULL,
  PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1
/*!50100 PARTITION BY LINEAR KEY (id)
PARTITIONS 32 */
1 row in set (0.00 sec)

mysql> ALTER TABLE p PARTITION BY LINEAR KEY ALGORITHM=2 (id) PARTITIONS 32;
Query OK, 0 rows affected (5.34 sec)
Records: 0  Duplicates: 0  Warnings: 0

mysql> SHOW CREATE TABLE p\G
*************************** 1. row ***************************
       Table: p
Create Table: CREATE TABLE `p` (
  `id` int(11) NOT NULL AUTO_INCREMENT,
  `cd` datetime NOT NULL,
  PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1
/*!50100 PARTITION BY LINEAR KEY (id)
PARTITIONS 32 */
1 row in set (0.00 sec)

Downgrading a table created using the default key-hashing used in MySQL 5.5 and later to enable its use by a MySQL 5.1 server is similar, except in this case you should useALGORITHM=1 to force the table's partitions to be rebuilt using the MySQL 5.1 key-hashing functions. It is recommended that you not do this except when necessary for compatibility with a MySQL 5.1 server, as the improved KEY hashing functions used by default in MySQL 5.5 and later provide fixes for a number of issues found in the older implementation.

Note

A table upgraded by means of ALTER TABLE ... PARTITION BY ALGORITHM=2 [LINEAR] KEY ... can no longer be used by a MySQL 5.1 server. (Such a table would need to be downgraded with ALTER TABLE ... PARTITION BY ALGORITHM=1 [LINEAR] KEY ... before it could be used again by a MySQL 5.1 server.)

The table that results from using an ALTER TABLE ... PARTITION BY statement must follow the same rules as one created using CREATE TABLE ... PARTITION BY. This includes the rules governing the relationship between any unique keys (including any primary key) that the table might have, and the column or columns used in the partitioning expression, as discussed inSection 22.6.1, “Partitioning Keys, Primary Keys, and Unique Keys”. The CREATE TABLE ... PARTITION BY rules for specifying the number of partitions also apply toALTER TABLE ... PARTITION BY.

The partitiondefinition clause for ALTER TABLE ADD PARTITION supports the same options as the clause of the same name for theCREATE TABLE statement. (SeeSection 13.1.18, “CREATE TABLE Statement”, for the syntax and description.) Suppose that you have the partitioned table created as shown here:

CREATE TABLE t1 (
    id INT,
    year_col INT
)
PARTITION BY RANGE (year_col) (
    PARTITION p0 VALUES LESS THAN (1991),
    PARTITION p1 VALUES LESS THAN (1995),
    PARTITION p2 VALUES LESS THAN (1999)
);

You can add a new partition p3 to this table for storing values less than 2002 as follows:

ALTER TABLE t1 ADD PARTITION (PARTITION p3 VALUES LESS THAN (2002));

DROP PARTITION can be used to drop one or more RANGE or LIST partitions. This statement cannot be used withHASH or KEY partitions; instead, use COALESCE PARTITION (see below). Any data that was stored in the dropped partitions named in the_partitionnames_ list is discarded. For example, given the tablet1 defined previously, you can drop the partitions named p0 andp1 as shown here:

ALTER TABLE t1 DROP PARTITION p0, p1;

ADD PARTITION and DROP PARTITION do not currently support IF [NOT] EXISTS.

DISCARD PARTITION ... TABLESPACE andIMPORT PARTITION ... TABLESPACE options extend theTransportable Tablespace feature to individualInnoDB table partitions. EachInnoDB table partition has its own tablespace file (.ibd file). TheTransportable Tablespace feature makes it easy to copy the tablespaces from a running MySQL server instance to another running instance, or to perform a restore on the same instance. Both options take a list of one or more comma-separated partition names. For example:

ALTER TABLE t1 DISCARD PARTITION p2, p3 TABLESPACE;
ALTER TABLE t1 IMPORT PARTITION p2, p3 TABLESPACE;

When runningDISCARD PARTITION ... TABLESPACE andIMPORT PARTITION ... TABLESPACE on subpartitioned tables, both partition and subpartition names are allowed. When a partition name is specified, subpartitions of that partition are included.

TheTransportable Tablespace feature also supports copying or restoring partitioned InnoDB tables. For more information, see Section 14.6.1.3, “Importing InnoDB Tables”.

Renames of partitioned tables are supported. You can rename individual partitions indirectly using ALTER TABLE ... REORGANIZE PARTITION; however, this operation copies the partition's data.

To delete rows from selected partitions, use theTRUNCATE PARTITION option. This option takes a comma-separated list of one or more partition names. For example, consider the table t1 as defined here:

CREATE TABLE t1 (
    id INT,
    year_col INT
)
PARTITION BY RANGE (year_col) (
    PARTITION p0 VALUES LESS THAN (1991),
    PARTITION p1 VALUES LESS THAN (1995),
    PARTITION p2 VALUES LESS THAN (1999),
    PARTITION p3 VALUES LESS THAN (2003),
    PARTITION p4 VALUES LESS THAN (2007)
);

To delete all rows from partition p0, use the following statement:

ALTER TABLE t1 TRUNCATE PARTITION p0;

The statement just shown has the same effect as the following DELETE statement:

DELETE FROM t1 WHERE year_col < 1991;

When truncating multiple partitions, the partitions do not have to be contiguous: This can greatly simplify delete operations on partitioned tables that would otherwise require very complex WHERE conditions if done with DELETE statements. For example, this statement deletes all rows from partitionsp1 and p3:

ALTER TABLE t1 TRUNCATE PARTITION p1, p3;

An equivalent DELETE statement is shown here:

DELETE FROM t1 WHERE
    (year_col >= 1991 AND year_col < 1995)
    OR
    (year_col >= 2003 AND year_col < 2007);

If you use the ALL keyword in place of the list of partition names, the statement acts on all table partitions.

TRUNCATE PARTITION merely deletes rows; it does not alter the definition of the table itself, or of any of its partitions.

To verify that the rows were dropped, check theINFORMATION_SCHEMA.PARTITIONS table, using a query such as this one:

SELECT PARTITION_NAME, TABLE_ROWS
    FROM INFORMATION_SCHEMA.PARTITIONS
    WHERE TABLE_NAME = 't1';

TRUNCATE PARTITION is supported only for partitioned tables that use theMyISAM,InnoDB, orMEMORY storage engine. It also works on BLACKHOLE tables (but has no effect). It is not supported forARCHIVE tables.

COALESCE PARTITION can be used with a table that is partitioned by HASH orKEY to reduce the number of partitions by_number_. Suppose that you have created table t2 as follows:

CREATE TABLE t2 (
    name VARCHAR (30),
    started DATE
)
PARTITION BY HASH( YEAR(started) )
PARTITIONS 6;

To reduce the number of partitions used byt2 from 6 to 4, use the following statement:

ALTER TABLE t2 COALESCE PARTITION 2;

The data contained in the last_number_ partitions are merged into the remaining partitions. In this case, partitions 4 and 5 are merged into the first 4 partitions (the partitions numbered 0, 1, 2, and 3).

To change some but not all the partitions used by a partitioned table, you can use REORGANIZE PARTITION. This statement can be used in several ways:

ALTER TABLE table ALGORITHM=INPLACE, REORGANIZE PARTITION;  

You cannot perform other DDL concurrently with online table reorganization—that is, no other DDL statements can be issued while an ALTER TABLE ... ALGORITHM=INPLACE, REORGANIZE PARTITION statement is executing. For more information about adding NDB Cluster data nodes online, seeSection 21.6.7, “Adding NDB Cluster Data Nodes Online”.
Note
ALTER TABLE ... ALGORITHM=INPLACE, REORGANIZE PARTITION does not work with tables which were created using the MAX_ROWS option, because it uses the constantMAX_ROWS value specified in the original CREATE TABLE statement to determine the number of partitions required, so no new partitions are created. Instead, you can use ALTER TABLE ... ALGORITHM=INPLACE, MAX_ROWS=_`rows`_ to increase the maximum number of rows for such a table; in this case, ALTER TABLE ... ALGORITHM=INPLACE, REORGANIZE PARTITION is not needed (and causes an error if executed). The value of rows must be greater than the value specified forMAX_ROWS in the originalCREATE TABLE statement for this to work.
Employing MAX_ROWS to force the number of table partitions is deprecated in NDB 7.5.4 and later; use PARTITION_BALANCE instead (seeSetting NDB_TABLE options).
Attempting to use REORGANIZE PARTITION without the_`partitionnames`_ INTO (_`partitiondefinitions`_) option on explicitly partitioned tables results in the error REORGANIZE PARTITION without parameters can only be used on auto-partitioned tables using HASH partitioning.

Note

For partitions that have not been explicitly named, MySQL automatically provides the default namesp0, p1,p2, and so on. The same is true with regard to subpartitions.

For more detailed information about and examples ofALTER TABLE ... REORGANIZE PARTITION statements, seeSection 22.3.1, “Management of RANGE and LIST Partitions”.

Several options provide partition maintenance and repair functionality analogous to that implemented for nonpartitioned tables by statements such asCHECK TABLE andREPAIR TABLE (which are also supported for partitioned tables; for more information, seeSection 13.7.2, “Table Maintenance Statements”). These include ANALYZE PARTITION, CHECK PARTITION, OPTIMIZE PARTITION,REBUILD PARTITION, and REPAIR PARTITION. Each of these options takes a_partitionnames_ clause consisting of one or more names of partitions, separated by commas. The partitions must already exist in the table to be altered. You can also use the ALL keyword in place of partitionnames, in which case the statement acts on all table partitions. For more information and examples, seeSection 22.3.4, “Maintenance of Partitions”.

Some MySQL storage engines, such asInnoDB, do not support per-partition optimization. For a partitioned table using such a storage engine, ALTER TABLE ... OPTIMIZE PARTITION causes the entire table to rebuilt and analyzed, and an appropriate warning to be issued. (Bug #11751825, Bug #42822)

To work around this problem, use the statementsALTER TABLE ... REBUILD PARTITION andALTER TABLE ... ANALYZE PARTITION instead.

The ANALYZE PARTITION, CHECK PARTITION, OPTIMIZE PARTITION, and REPAIR PARTITION options are not permitted for tables which are not partitioned.

In MySQL 5.7.9 and later, you can use ALTER TABLE ... UPGRADE PARTITIONING to upgrade a partitionedInnoDB table that was created with the old generic partitioning handler to theInnoDB native partitioning employed in MySQL 5.7.6 and later. Also beginning with MySQL 5.7.9, themysql_upgrade utility checks for such partitioned InnoDB tables and attempts to upgrade them to native partitioning as part of its normal operations.

Important

Partitioned InnoDB tables that do not use the InnoDB native partitioning handler cannot be used in MySQL 8.0 or later.ALTER TABLE ... UPGRADE PARTITIONING is not supported in MySQL 8.0 or later; therefore, any partitioned InnoDB tables that employ the generic handler must be upgraded to the InnoDB native handler before upgrading your MySQL installation to MySQL 8.0 or later.

REMOVE PARTITIONING enables you to remove a table's partitioning without otherwise affecting the table or its data. This option can be combined with otherALTER TABLE options such as those used to add, drop, or rename columns or indexes.

Using the ENGINE option withALTER TABLE changes the storage engine used by the table without affecting the partitioning.