Partitioning-related clauses for ALTER
TABLE can be used with partitioned tables for
repartitioning, to add, drop, discard, import, merge, and split
partitions, and to perform partitioning maintenance.
Simply using a
partition_optionsclause withALTER TABLEon a partitioned table repartitions the table according to the partitioning scheme defined by thepartition_options. This clause always begins withPARTITION BY, and follows the same syntax and other rules as apply to thepartition_optionsclause forCREATE TABLE(for more detailed information, see Section 15.1.20, “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 theidcolumn as the partitioning key, into 8 partitions by means of this statement:ALTER TABLE t1 PARTITION BY HASH(id) PARTITIONS 8;MySQL supports an
ALGORITHMoption with[SUB]PARTITION BY [LINEAR] KEY.ALGORITHM=1causes the server to use the same key-hashing functions as MySQL 5.1 when computing the placement of rows in partitions;ALGORITHM=2means that the server employs the key-hashing functions implemented and used by default for newKEYpartitioned 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 usingALGORITHM=2. This option is intended for use chiefly when upgrading or downgrading[LINEAR] KEYpartitioned tables between MySQL 5.1 and later MySQL versions, or for creating tables partitioned byKEYorLINEAR KEYon a MySQL 5.5 or later server which can be used on a MySQL 5.1 server.The table that results from using an
ALTER TABLE ... PARTITION BYstatement must follow the same rules as one created usingCREATE 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 in Section 26.6.1, “Partitioning Keys, Primary Keys, and Unique Keys”. TheCREATE TABLE ... PARTITION BYrules for specifying the number of partitions also apply toALTER TABLE ... PARTITION BY.The
partition_definitionclause forALTER TABLE ADD PARTITIONsupports the same options as the clause of the same name for theCREATE TABLEstatement. (See Section 15.1.20, “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
p3to this table for storing values less than2002as follows:ALTER TABLE t1 ADD PARTITION (PARTITION p3 VALUES LESS THAN (2002));DROP PARTITIONcan be used to drop one or moreRANGEorLISTpartitions. This statement cannot be used withHASHorKEYpartitions; instead, useCOALESCE PARTITION(see later in this section). Any data that was stored in the dropped partitions named in thepartition_nameslist is discarded. For example, given the tablet1defined previously, you can drop the partitions namedp0andp1as shown here:ALTER TABLE t1 DROP PARTITION p0, p1;NoteDROP PARTITIONdoes not work with tables that use theNDBstorage engine. See Section 26.3.1, “Management of RANGE and LIST Partitions”, and Section 25.2.7, “Known Limitations of NDB Cluster”.ADD PARTITIONandDROP PARTITIONdo not currently supportIF [NOT] EXISTS.The
DISCARD PARTITION ... TABLESPACEandIMPORT PARTITION ... TABLESPACEoptions extend the Transportable Tablespace feature to individualInnoDBtable partitions. EachInnoDBtable partition has its own tablespace file (.ibdfile). The Transportable 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 comma-separated list of one or more partition names. For example:ALTER TABLE t1 DISCARD PARTITION p2, p3 TABLESPACE;ALTER TABLE t1 IMPORT PARTITION p2, p3 TABLESPACE;When running
DISCARD PARTITION ... TABLESPACEandIMPORT PARTITION ... TABLESPACEon subpartitioned tables, both partition and subpartition names are allowed. When a partition name is specified, subpartitions of that partition are included.The Transportable Tablespace feature also supports copying or restoring partitioned
InnoDBtables. For more information, see Section 17.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 the
TRUNCATE PARTITIONoption. This option takes a list of one or more comma-separated partition names. Consider the tablet1created by this statement: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
DELETEstatement: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
WHEREconditions if done withDELETEstatements. For example, this statement deletes all rows from partitionsp1andp3:ALTER TABLE t1 TRUNCATE PARTITION p1, p3;An equivalent
DELETEstatement 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
ALLkeyword in place of the list of partition names, the statement acts on all table partitions.TRUNCATE PARTITIONmerely 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 the
INFORMATION_SCHEMA.PARTITIONStable, using a query such as this one:SELECT PARTITION_NAME, TABLE_ROWS FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME = 't1';COALESCE PARTITIONcan be used with a table that is partitioned byHASHorKEYto reduce the number of partitions bynumber. Suppose that you have created tablet2as follows:CREATE TABLE t2 ( name VARCHAR (30), started DATE ) PARTITION BY HASH( YEAR(started) ) PARTITIONS 6;To reduce the number of partitions used by
t2from 6 to 4, use the following statement:ALTER TABLE t2 COALESCE PARTITION 2;The data contained in the last
numberpartitions is 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:To merge a set of partitions into a single partition. This is done by naming several partitions in the
partition_nameslist and supplying a single definition forpartition_definition.To split an existing partition into several partitions. Accomplish this by naming a single partition for
partition_namesand providing multiplepartition_definitions.To change the ranges for a subset of partitions defined using
VALUES LESS THANor the value lists for a subset of partitions defined usingVALUES IN.
NoteFor partitions that have not been explicitly named, MySQL automatically provides the default names
p0,p1,p2, and so on. The same is true with regard to subpartitions.For more detailed information about and examples of
ALTER TABLE ... REORGANIZE PARTITIONstatements, see Section 26.3.1, “Management of RANGE and LIST Partitions”.To exchange a table partition or subpartition with a table, use the
ALTER TABLE ... EXCHANGE PARTITIONstatement—that is, to move any existing rows in the partition or subpartition to the nonpartitioned table, and any existing rows in the nonpartitioned table to the table partition or subpartition.Once one or more columns have been added to a partitioned table using
ALGORITHM=INSTANT, it is no longer possible to exchange partitions with that table.For usage information and examples, see Section 26.3.3, “Exchanging Partitions and Subpartitions with Tables”.
Several options provide partition maintenance and repair functionality analogous to that implemented for nonpartitioned tables by statements such as
CHECK TABLEandREPAIR TABLE(which are also supported for partitioned tables; for more information, see Section 15.7.3, “Table Maintenance Statements”). These includeANALYZE PARTITION,CHECK PARTITION,OPTIMIZE PARTITION,REBUILD PARTITION, andREPAIR PARTITION. Each of these options takes apartition_namesclause consisting of one or more names of partitions, separated by commas. The partitions must already exist in the target table. You can also use theALLkeyword in place ofpartition_names, in which case the statement acts on all table partitions. For more information and examples, see Section 26.3.4, “Maintenance of Partitions”.InnoDBdoes not currently support per-partition optimization;ALTER TABLE ... OPTIMIZE PARTITIONcauses the entire table to rebuilt and analyzed, and an appropriate warning to be issued. (Bug #11751825, Bug #42822) To work around this problem, useALTER TABLE ... REBUILD PARTITIONandALTER TABLE ... ANALYZE PARTITIONinstead.The
ANALYZE PARTITION,CHECK PARTITION,OPTIMIZE PARTITION, andREPAIR PARTITIONoptions are not supported for tables which are not partitioned.REMOVE PARTITIONINGenables you to remove a table's partitioning without otherwise affecting the table or its data. This option can be combined with otherALTER TABLEoptions such as those used to add, drop, or rename columns or indexes.Using the
ENGINEoption withALTER TABLEchanges the storage engine used by the table without affecting the partitioning. The target storage engine must provide its own partitioning handler. Only theInnoDBandNDBstorage engines have native partitioning handlers.
It is possible for an ALTER TABLE
statement to contain a PARTITION BY or
REMOVE PARTITIONING clause in an addition to
other alter specifications, but the PARTITION
BY or REMOVE PARTITIONING clause
must be specified last after any other specifications.
The ADD PARTITION, DROP
PARTITION, COALESCE PARTITION,
REORGANIZE PARTITION, ANALYZE
PARTITION, CHECK PARTITION, and
REPAIR PARTITION options cannot be combined
with other alter specifications in a single ALTER
TABLE, since the options just listed act on individual
partitions. For more information, see
Section 15.1.9.1, “ALTER TABLE Partition Operations”.
Only a single instance of any one of the following options can
be used in a given ALTER TABLE
statement: PARTITION BY, ADD
PARTITION, DROP PARTITION,
TRUNCATE PARTITION, EXCHANGE
PARTITION, REORGANIZE PARTITION, or
COALESCE PARTITION, ANALYZE
PARTITION, CHECK PARTITION,
OPTIMIZE PARTITION, REBUILD
PARTITION, REMOVE PARTITIONING.
For example, the following two statements are invalid:
ALTER TABLE t1 ANALYZE PARTITION p1, ANALYZE PARTITION p2;
ALTER TABLE t1 ANALYZE PARTITION p1, CHECK PARTITION p2;
In the first case, you can analyze partitions
p1 and p2 of table
t1 concurrently using a single statement with
a single ANALYZE PARTITION option that lists
both of the partitions to be analyzed, like this:
ALTER TABLE t1 ANALYZE PARTITION p1, p2;
In the second case, it is not possible to perform
ANALYZE and CHECK
operations on different partitions of the same table
concurrently. Instead, you must issue two separate statements,
like this:
ALTER TABLE t1 ANALYZE PARTITION p1;
ALTER TABLE t1 CHECK PARTITION p2;
REBUILD operations are currently unsupported
for subpartitions. The REBUILD keyword is
expressly disallowed with subpartitions, and causes
ALTER TABLE to fail with an error if so used.
CHECK PARTITION and REPAIR
PARTITION operations fail when the partition to be
checked or repaired contains any duplicate key errors.
For more information about these statements, see Section 26.3.4, “Maintenance of Partitions”.