In MySQL 8.0, it is possible to exchange a table
partition or subpartition with a table using ALTER
TABLE , where
pt EXCHANGE PARTITION
p WITH TABLE
ntpt is the partitioned table and
p is the partition or subpartition of
pt to be exchanged with unpartitioned
table nt, provided that the following
statements are true:
Table
ntis not itself partitioned.Table
ntis not a temporary table.The structures of tables
ptandntare otherwise identical.Table
ntcontains no foreign key references, and no other table has any foreign keys that refer tont.There are no rows in
ntthat lie outside the boundaries of the partition definition forp. This condition does not apply ifWITHOUT VALIDATIONis used.Both tables must use the same character set and collation.
For
InnoDBtables, both tables must use the same row format. To determine the row format of anInnoDBtable, queryINFORMATION_SCHEMA.INNODB_TABLES.Any partition-level
MAX_ROWSsetting forpmust be the same as the table-levelMAX_ROWSvalue set fornt. The setting for any partition-levelMIN_ROWSsetting forpmust also be the same any table-levelMIN_ROWSvalue set fornt.This is true in either case whether not
pthas an explicit table-levelMAX_ROWSorMIN_ROWSoption in effect.The
AVG_ROW_LENGTHcannot differ between the two tablesptandnt.ptdoes not have any partitions that use theDATA DIRECTORYoption. This restriction is lifted forInnoDBtables in MySQL 8.0.14 and later.INDEX DIRECTORYcannot differ between the table and the partition to be exchanged with it.No table or partition
TABLESPACEoptions can be used in either of the tables.
In addition to the ALTER,
INSERT, and
CREATE privileges usually
required for ALTER TABLE
statements, you must have the
DROP privilege to perform
ALTER TABLE ...
EXCHANGE PARTITION.
You should also be aware of the following effects of
ALTER TABLE ...
EXCHANGE PARTITION:
Executing
ALTER TABLE ... EXCHANGE PARTITIONdoes not invoke any triggers on either the partitioned table or the table to be exchanged.Any
AUTO_INCREMENTcolumns in the exchanged table are reset.The
IGNOREkeyword has no effect when used withALTER TABLE ... EXCHANGE PARTITION.
The syntax for
ALTER TABLE ...
EXCHANGE PARTITION is shown here, where
pt is the partitioned table,
p is the partition (or subpartition)
to be exchanged, and nt is the
nonpartitioned table to be exchanged with
p:
ALTER TABLE pt
EXCHANGE PARTITION p
WITH TABLE nt;
Optionally, you can append WITH VALIDATION or
WITHOUT VALIDATION. When WITHOUT
VALIDATION is specified, the
ALTER TABLE ...
EXCHANGE PARTITION operation does not perform any
row-by-row validation when exchanging a partition a
nonpartitioned table, allowing database administrators to assume
responsibility for ensuring that rows are within the boundaries
of the partition definition. WITH VALIDATION
is the default.
One and only one partition or subpartition may be exchanged with
one and only one nonpartitioned table in a single
ALTER TABLE
EXCHANGE PARTITION statement. To exchange multiple
partitions or subpartitions, use multiple
ALTER TABLE
EXCHANGE PARTITION statements. EXCHANGE
PARTITION may not be combined with other
ALTER TABLE options. The
partitioning and (if applicable) subpartitioning used by the
partitioned table may be of any type or types supported in MySQL
8.0.
Exchanging a Partition with a Nonpartitioned Table
Suppose that a partitioned table e has been
created and populated using the following SQL statements:
CREATE TABLE e (
id INT NOT NULL,
fname VARCHAR(30),
lname VARCHAR(30)
)
PARTITION BY RANGE (id) (
PARTITION p0 VALUES LESS THAN (50),
PARTITION p1 VALUES LESS THAN (100),
PARTITION p2 VALUES LESS THAN (150),
PARTITION p3 VALUES LESS THAN (MAXVALUE)
);
INSERT INTO e VALUES
(1669, "Jim", "Smith"),
(337, "Mary", "Jones"),
(16, "Frank", "White"),
(2005, "Linda", "Black");
Now we create a nonpartitioned copy of e
named e2. This can be done using the
mysql client as shown here:
mysql> CREATE TABLE e2 LIKE e;
Query OK, 0 rows affected (0.04 sec)
mysql> ALTER TABLE e2 REMOVE PARTITIONING;
Query OK, 0 rows affected (0.07 sec)
Records: 0 Duplicates: 0 Warnings: 0
You can see which partitions in table e
contain rows by querying the Information Schema
PARTITIONS table, like this:
mysql> SELECT PARTITION_NAME, TABLE_ROWS
FROM INFORMATION_SCHEMA.PARTITIONS
WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 1 |
| p1 | 0 |
| p2 | 0 |
| p3 | 3 |
+----------------+------------+
2 rows in set (0.00 sec)
For partitioned InnoDB tables, the row
count given in the TABLE_ROWS column of the
Information Schema PARTITIONS
table is only an estimated value used in SQL optimization, and
is not always exact.
To exchange partition p0 in table
e with table e2, you can
use
ALTER
TABLE, as shown here:
mysql> ALTER TABLE e EXCHANGE PARTITION p0 WITH TABLE e2;
Query OK, 0 rows affected (0.04 sec)
More precisely, the statement just issued causes any rows found
in the partition to be swapped with those found in the table.
You can observe how this has happened by querying the
Information Schema PARTITIONS
table, as before. The table row that was previously found in
partition p0 is no longer present:
mysql> SELECT PARTITION_NAME, TABLE_ROWS
FROM INFORMATION_SCHEMA.PARTITIONS
WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 0 |
| p1 | 0 |
| p2 | 0 |
| p3 | 3 |
+----------------+------------+
4 rows in set (0.00 sec)
If you query table e2, you can see that the
“missing” row can now be found there:
mysql> SELECT * FROM e2;
+----+-------+-------+
| id | fname | lname |
+----+-------+-------+
| 16 | Frank | White |
+----+-------+-------+
1 row in set (0.00 sec)
The table to be exchanged with the partition does not
necessarily have to be empty. To demonstrate this, we first
insert a new row into table e, making sure
that this row is stored in partition p0 by
choosing an id column value that is less than
50, and verifying this afterward by querying the
PARTITIONS table:
mysql> INSERT INTO e VALUES (41, "Michael", "Green");
Query OK, 1 row affected (0.05 sec)
mysql> SELECT PARTITION_NAME, TABLE_ROWS
FROM INFORMATION_SCHEMA.PARTITIONS
WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 1 |
| p1 | 0 |
| p2 | 0 |
| p3 | 3 |
+----------------+------------+
4 rows in set (0.00 sec)
Now we once again exchange partition p0 with
table e2 using the same
ALTER
TABLE statement as previously:
mysql> ALTER TABLE e EXCHANGE PARTITION p0 WITH TABLE e2;
Query OK, 0 rows affected (0.28 sec)
The output of the following queries shows that the table row
that was stored in partition p0 and the table
row that was stored in table e2, prior to
issuing the
ALTER
TABLE statement, have now switched places:
mysql> SELECT * FROM e;
+------+-------+-------+
| id | fname | lname |
+------+-------+-------+
| 16 | Frank | White |
| 1669 | Jim | Smith |
| 337 | Mary | Jones |
| 2005 | Linda | Black |
+------+-------+-------+
4 rows in set (0.00 sec)
mysql> SELECT PARTITION_NAME, TABLE_ROWS
FROM INFORMATION_SCHEMA.PARTITIONS
WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 1 |
| p1 | 0 |
| p2 | 0 |
| p3 | 3 |
+----------------+------------+
4 rows in set (0.00 sec)
mysql> SELECT * FROM e2;
+----+---------+-------+
| id | fname | lname |
+----+---------+-------+
| 41 | Michael | Green |
+----+---------+-------+
1 row in set (0.00 sec)
Nonmatching Rows
You should keep in mind that any rows found in the
nonpartitioned table prior to issuing the
ALTER TABLE ...
EXCHANGE PARTITION statement must meet the conditions
required for them to be stored in the target partition;
otherwise, the statement fails. To see how this occurs, first
insert a row into e2 that is outside the
boundaries of the partition definition for partition
p0 of table e. For
example, insert a row with an id column value
that is too large; then, try to exchange the table with the
partition again:
mysql> INSERT INTO e2 VALUES (51, "Ellen", "McDonald");
Query OK, 1 row affected (0.08 sec)
mysql> ALTER TABLE e EXCHANGE PARTITION p0 WITH TABLE e2;
ERROR 1707 (HY000): Found row that does not match the partition
Only the WITHOUT VALIDATION option would
permit this operation to succeed:
mysql> ALTER TABLE e EXCHANGE PARTITION p0 WITH TABLE e2 WITHOUT VALIDATION;
Query OK, 0 rows affected (0.02 sec)
When a partition is exchanged with a table that contains rows
that do not match the partition definition, it is the
responsibility of the database administrator to fix the
non-matching rows, which can be performed using
REPAIR TABLE or
ALTER
TABLE ... REPAIR PARTITION.
Exchanging Partitions Without Row-By-Row Validation
To avoid time consuming validation when exchanging a partition
with a table that has many rows, it is possible to skip the
row-by-row validation step by appending WITHOUT
VALIDATION to the
ALTER
TABLE ... EXCHANGE PARTITION statement.
The following example compares the difference between execution
times when exchanging a partition with a nonpartitioned table,
with and without validation. The partitioned table (table
e) contains two partitions of 1 million rows
each. The rows in p0 of table e are removed and p0 is exchanged
with a nonpartitioned table of 1 million rows. The WITH
VALIDATION operation takes 0.74 seconds. By
comparison, the WITHOUT VALIDATION operation
takes 0.01 seconds.
# Create a partitioned table with 1 million rows in each partition
CREATE TABLE e (
id INT NOT NULL,
fname VARCHAR(30),
lname VARCHAR(30)
)
PARTITION BY RANGE (id) (
PARTITION p0 VALUES LESS THAN (1000001),
PARTITION p1 VALUES LESS THAN (2000001),
);
mysql> SELECT COUNT(*) FROM e;
| COUNT(*) |
+----------+
| 2000000 |
+----------+
1 row in set (0.27 sec)
# View the rows in each partition
SELECT PARTITION_NAME, TABLE_ROWS FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME = 'e';
+----------------+-------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+-------------+
| p0 | 1000000 |
| p1 | 1000000 |
+----------------+-------------+
2 rows in set (0.00 sec)
# Create a nonpartitioned table of the same structure and populate it with 1 million rows
CREATE TABLE e2 (
id INT NOT NULL,
fname VARCHAR(30),
lname VARCHAR(30)
);
mysql> SELECT COUNT(*) FROM e2;
+----------+
| COUNT(*) |
+----------+
| 1000000 |
+----------+
1 row in set (0.24 sec)
# Create another nonpartitioned table of the same structure and populate it with 1 million rows
CREATE TABLE e3 (
id INT NOT NULL,
fname VARCHAR(30),
lname VARCHAR(30)
);
mysql> SELECT COUNT(*) FROM e3;
+----------+
| COUNT(*) |
+----------+
| 1000000 |
+----------+
1 row in set (0.25 sec)
# Drop the rows from p0 of table e
mysql> DELETE FROM e WHERE id < 1000001;
Query OK, 1000000 rows affected (5.55 sec)
# Confirm that there are no rows in partition p0
mysql> SELECT PARTITION_NAME, TABLE_ROWS FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 0 |
| p1 | 1000000 |
+----------------+------------+
2 rows in set (0.00 sec)
# Exchange partition p0 of table e with the table e2 'WITH VALIDATION'
mysql> ALTER TABLE e EXCHANGE PARTITION p0 WITH TABLE e2 WITH VALIDATION;
Query OK, 0 rows affected (0.74 sec)
# Confirm that the partition was exchanged with table e2
mysql> SELECT PARTITION_NAME, TABLE_ROWS FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 1000000 |
| p1 | 1000000 |
+----------------+------------+
2 rows in set (0.00 sec)
# Once again, drop the rows from p0 of table e
mysql> DELETE FROM e WHERE id < 1000001;
Query OK, 1000000 rows affected (5.55 sec)
# Confirm that there are no rows in partition p0
mysql> SELECT PARTITION_NAME, TABLE_ROWS FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 0 |
| p1 | 1000000 |
+----------------+------------+
2 rows in set (0.00 sec)
# Exchange partition p0 of table e with the table e3 'WITHOUT VALIDATION'
mysql> ALTER TABLE e EXCHANGE PARTITION p0 WITH TABLE e3 WITHOUT VALIDATION;
Query OK, 0 rows affected (0.01 sec)
# Confirm that the partition was exchanged with table e3
mysql> SELECT PARTITION_NAME, TABLE_ROWS FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME = 'e';
+----------------+------------+
| PARTITION_NAME | TABLE_ROWS |
+----------------+------------+
| p0 | 1000000 |
| p1 | 1000000 |
+----------------+------------+
2 rows in set (0.00 sec)
If a partition is exchanged with a table that contains rows that
do not match the partition definition, it is the responsibility
of the database administrator to fix the non-matching rows,
which can be performed using REPAIR
TABLE or
ALTER
TABLE ... REPAIR PARTITION.
Exchanging a Subpartition with a Nonpartitioned Table
You can also exchange a subpartition of a subpartitioned table
(see Section 26.2.6, “Subpartitioning”) with a
nonpartitioned table using an
ALTER TABLE ...
EXCHANGE PARTITION statement. In the following
example, we first create a table es that is
partitioned by RANGE and subpartitioned by
KEY, populate this table as we did table
e, and then create an empty, nonpartitioned
copy es2 of the table, as shown here:
mysql> CREATE TABLE es (
-> id INT NOT NULL,
-> fname VARCHAR(30),
-> lname VARCHAR(30)
-> )
-> PARTITION BY RANGE (id)
-> SUBPARTITION BY KEY (lname)
-> SUBPARTITIONS 2 (
-> PARTITION p0 VALUES LESS THAN (50),
-> PARTITION p1 VALUES LESS THAN (100),
-> PARTITION p2 VALUES LESS THAN (150),
-> PARTITION p3 VALUES LESS THAN (MAXVALUE)
-> );
Query OK, 0 rows affected (2.76 sec)
mysql> INSERT INTO es VALUES
-> (1669, "Jim", "Smith"),
-> (337, "Mary", "Jones"),
-> (16, "Frank", "White"),
-> (2005, "Linda", "Black");
Query OK, 4 rows affected (0.04 sec)
Records: 4 Duplicates: 0 Warnings: 0
mysql> CREATE TABLE es2 LIKE es;
Query OK, 0 rows affected (1.27 sec)
mysql> ALTER TABLE es2 REMOVE PARTITIONING;
Query OK, 0 rows affected (0.70 sec)
Records: 0 Duplicates: 0 Warnings: 0
Although we did not explicitly name any of the subpartitions
when creating table es, we can obtain
generated names for these by including the
SUBPARTITION_NAME column of the
PARTITIONS table from
INFORMATION_SCHEMA when selecting from that
table, as shown here:
mysql> SELECT PARTITION_NAME, SUBPARTITION_NAME, TABLE_ROWS
-> FROM INFORMATION_SCHEMA.PARTITIONS
-> WHERE TABLE_NAME = 'es';
+----------------+-------------------+------------+
| PARTITION_NAME | SUBPARTITION_NAME | TABLE_ROWS |
+----------------+-------------------+------------+
| p0 | p0sp0 | 1 |
| p0 | p0sp1 | 0 |
| p1 | p1sp0 | 0 |
| p1 | p1sp1 | 0 |
| p2 | p2sp0 | 0 |
| p2 | p2sp1 | 0 |
| p3 | p3sp0 | 3 |
| p3 | p3sp1 | 0 |
+----------------+-------------------+------------+
8 rows in set (0.00 sec)
The following
ALTER
TABLE statement exchanges subpartition
p3sp0 in table es with the
nonpartitioned table es2:
mysql> ALTER TABLE es EXCHANGE PARTITION p3sp0 WITH TABLE es2;
Query OK, 0 rows affected (0.29 sec)You can verify that the rows were exchanged by issuing the following queries:
mysql> SELECT PARTITION_NAME, SUBPARTITION_NAME, TABLE_ROWS
-> FROM INFORMATION_SCHEMA.PARTITIONS
-> WHERE TABLE_NAME = 'es';
+----------------+-------------------+------------+
| PARTITION_NAME | SUBPARTITION_NAME | TABLE_ROWS |
+----------------+-------------------+------------+
| p0 | p0sp0 | 1 |
| p0 | p0sp1 | 0 |
| p1 | p1sp0 | 0 |
| p1 | p1sp1 | 0 |
| p2 | p2sp0 | 0 |
| p2 | p2sp1 | 0 |
| p3 | p3sp0 | 0 |
| p3 | p3sp1 | 0 |
+----------------+-------------------+------------+
8 rows in set (0.00 sec)
mysql> SELECT * FROM es2;
+------+-------+-------+
| id | fname | lname |
+------+-------+-------+
| 1669 | Jim | Smith |
| 337 | Mary | Jones |
| 2005 | Linda | Black |
+------+-------+-------+
3 rows in set (0.00 sec)If a table is subpartitioned, you can exchange only a subpartition of the table—not an entire partition—with an unpartitioned table, as shown here:
mysql> ALTER TABLE es EXCHANGE PARTITION p3 WITH TABLE es2;
ERROR 1704 (HY000): Subpartitioned table, use subpartition instead of partitionTable structures are compared in a strict fashion; the number, order, names, and types of columns and indexes of the partitioned table and the nonpartitioned table must match exactly. In addition, both tables must use the same storage engine:
mysql> CREATE TABLE es3 LIKE e;
Query OK, 0 rows affected (1.31 sec)
mysql> ALTER TABLE es3 REMOVE PARTITIONING;
Query OK, 0 rows affected (0.53 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> SHOW CREATE TABLE es3\G
*************************** 1. row ***************************
Table: es3
Create Table: CREATE TABLE `es3` (
`id` int(11) NOT NULL,
`fname` varchar(30) DEFAULT NULL,
`lname` varchar(30) DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
1 row in set (0.00 sec)
mysql> ALTER TABLE es3 ENGINE = MyISAM;
Query OK, 0 rows affected (0.15 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> ALTER TABLE es EXCHANGE PARTITION p3sp0 WITH TABLE es3;
ERROR 1497 (HY000): The mix of handlers in the partitions is not allowed in this version of MySQL