If you are transporting tables that are encrypted using the
InnoDB tablespace encryption, see
Limitations and Usage Notes
before you begin for additional procedural information.
Example 1: Copying an InnoDB Table From One Server To Another
This procedure demonstrates how to copy a regular
InnoDB table from a running MySQL server
instance to another running instance. The same procedure with
minor adjustments can be used to perform a full table restore on
the same instance.
On the source server, create a table if one does not exist:
mysql> use test; mysql> CREATE TABLE t(c1 INT) engine=InnoDB;
On the destination server, create a table if one does not exist:
mysql> use test; mysql> CREATE TABLE t(c1 INT) engine=InnoDB;
On the destination server, discard the existing tablespace. (Before a tablespace can be imported,
InnoDBmust discard the tablespace that is attached to the receiving table.)mysql> ALTER TABLE t DISCARD TABLESPACE;
On the source server, run
FLUSH TABLES ... FOR EXPORTto quiesce the table and create the.cfgmetadata file:mysql> use test; mysql> FLUSH TABLES t FOR EXPORT;
The metadata (
.cfg) is created in theInnoDBdata directory.NoteFLUSH TABLES ... FOR EXPORTis available as of MySQL 5.6.6. The statement ensures that changes to the named table have been flushed to disk so that a binary table copy can be made while the server is running. WhenFLUSH TABLES ... FOR EXPORTis run,InnoDBproduces a.cfgfile in the same database directory as the table. The.cfgfile contains metadata used for schema verification when importing the tablespace file.Copy the
.ibdfile and.cfgmetadata file from the source server to the destination server. For example:shell> scp
/path/to/datadir/test/t.{ibd,cfg} destination-server:/path/to/datadir/testNoteThe
.ibdfile and.cfgfile must be copied before releasing the shared locks, as described in the next step.On the source server, use
UNLOCK TABLESto release the locks acquired byFLUSH TABLES ... FOR EXPORT:mysql> use test; mysql> UNLOCK TABLES;
On the destination server, import the tablespace:
mysql> use test; mysql> ALTER TABLE t IMPORT TABLESPACE;
NoteThe
ALTER TABLE ... IMPORT TABLESPACEfeature does not enforce foreign key constraints on imported data. If there are foreign key constraints between tables, all tables should be exported at the same (logical) point in time. In this case you would stop updating the tables, commit all transactions, acquire shared locks on the tables, and then perform the export operation.
Example 2: Copying an InnoDB Partitioned Table From One Server To Another
This procedure demonstrates how to copy a partitioned
InnoDB table from a running MySQL server
instance to another running instance. The same procedure with
minor adjustments can be used to perform a full restore of a
partitioned InnoDB table on the same
instance.
On the source server, create a partitioned table if one does not exist. In the following example, a table with three partitions (p0, p1, p2) is created:
mysql> use test; mysql> CREATE TABLE t1 (i int) ENGINE = InnoDB PARTITION BY KEY (i) PARTITIONS 3;
In the
/directory, you will see a separate tablespace (datadir/test.ibd) file for each of the three partitions.mysql> \! ls
/path/to/datadir/test/ db.opt t1.frm t1#P#p0.ibd t1#P#p1.ibd t1#P#p2.ibdOn the destination server, create the same partitioned table:
mysql> use test; mysql> CREATE TABLE t1 (i int) ENGINE = InnoDB PARTITION BY KEY (i) PARTITIONS 3;
In the
/directory, you will see a separate tablespace (datadir/test.ibd) file for each of the three partitions.mysql> \! ls
/path/to/datadir/test/ db.opt t1.frm t1#P#p0.ibd t1#P#p1.ibd t1#P#p2.ibdOn the destination server, discard the tablespace for the partitioned table. (Before the tablespace can be imported on the destination server, the tablespace that is attached to the receiving table must be discarded.)
mysql> ALTER TABLE t1 DISCARD TABLESPACE;
The three
.ibdfiles that make up the tablespace for the partitioned table are discarded from the/directory, leaving the following files:datadir/testmysql> \! ls
/path/to/datadir/test/ db.opt t1.frmOn the source server, run
FLUSH TABLES ... FOR EXPORTto quiesce the partitioned table and create the.cfgmetadata files:mysql> use test; mysql> FLUSH TABLES t1 FOR EXPORT;
Metadata (
.cfg) files, one for each tablespace (.ibd) file, are created in the/directory on the source server:datadir/testmysql> \! ls
/path/to/datadir/test/ db.opt t1#P#p0.ibd t1#P#p1.ibd t1#P#p2.ibd t1.frm t1#P#p0.cfg t1#P#p1.cfg t1#P#p2.cfgNoteFLUSH TABLES ... FOR EXPORTstatement ensures that changes to the named table have been flushed to disk so that binary table copy can be made while the server is running. WhenFLUSH TABLES ... FOR EXPORTis run,InnoDBproduces a.cfgmetadata file for the table's tablespace files in the same database directory as the table. The.cfgfiles contain metadata used for schema verification when importing tablespace files.FLUSH TABLES ... FOR EXPORTcan only be run on the table, not on individual table partitions.Copy the
.ibdand.cfgfiles from the source server database directory to the destination server database directory. For example:shell> scp
/path/to/datadir/test/t1*.{ibd,cfg} destination-server:/path/to/datadir/testNoteThe
.ibdand.cfgfiles must be copied before releasing the shared locks, as described in the next step.On the source server, use
UNLOCK TABLESto release the locks acquired byFLUSH TABLES ... FOR EXPORT:mysql> use test; mysql> UNLOCK TABLES;
On the destination server, import the tablespace for the partitioned table:
mysql> use test; mysql> ALTER TABLE t1 IMPORT TABLESPACE;
Example 3: Copying InnoDB Table Partitions From One Server To Another
This procedure demonstrates how to copy
InnoDB table partitions from a running MySQL
server instance to another running instance. The same procedure
with minor adjustments can be used to perform a restore of
InnoDB table partitions on the same instance.
In the following example, a partitioned table with four
partitions (p0, p1, p2, p3) is created on the source server. Two
of the partitions (p2 and p3) are copied to the destination
server.
On the source server, create a partitioned table if one does not exist. In the following example, a table with four partitions (p0, p1, p2, p3) is created:
mysql> use test; mysql> CREATE TABLE t1 (i int) ENGINE = InnoDB PARTITION BY KEY (i) PARTITIONS 4;
In the
/directory, you will see a separate tablespace (datadir/test.ibd) file for each of the four partitions.mysql> \! ls
/path/to/datadir/test/ db.opt t1.frm t1#P#p0.ibd t1#P#p1.ibd t1#P#p2.ibd t1#P#p3.ibdOn the destination server, create the same partitioned table:
mysql> use test; mysql> CREATE TABLE t1 (i int) ENGINE = InnoDB PARTITION BY KEY (i) PARTITIONS 4;
In the
/directory, you will see a separate tablespace (datadir/test.ibd) file for each of the four partitions.mysql> \! ls
/path/to/datadir/test/ db.opt t1.frm t1#P#p0.ibd t1#P#p1.ibd t1#P#p2.ibd t1#P#p3.ibdOn the destination server, discard the tablespace partitions that you plan to import from the source server. (Before tablespace partitions can be imported on the destination server, the corresponding partitions that are attached to the receiving table must be discarded.)
mysql> ALTER TABLE t1 DISCARD PARTITION p2, p3 TABLESPACE;
The
.ibdfiles for the two discarded partitions are removed from the/directory on the destination server, leaving the following files:datadir/testmysql> \! ls
/path/to/datadir/test/ db.opt t1.frm t1#P#p0.ibd t1#P#p1.ibdNoteWhen
ALTER TABLE ... DISCARD PARTITION ... TABLESPACEis run on subpartitioned tables, both partition and subpartition table names are allowed. When a partition name is specified, subpartitions of that partition are included in the operation.On the source server, run
FLUSH TABLES ... FOR EXPORTto quiesce the partitioned table and create the.cfgmetadata files.mysql> use test; mysql> FLUSH TABLES t1 FOR EXPORT;
The metadata files (
.cfgfiles) are created in the/directory on the source server. There is adatadir/test.cfgfile for each tablespace (.ibd) file.mysql> \! ls
/path/to/datadir/test/ db.opt t1#P#p0.ibd t1#P#p1.ibd t1#P#p2.ibd t1#P#p3.ibd t1.frm t1#P#p0.cfg t1#P#p1.cfg t1#P#p2.cfg t1#P#p3.cfgNoteFLUSH TABLES ... FOR EXPORTstatement ensures that changes to the named table have been flushed to disk so that binary table copy can be made while the server is running. WhenFLUSH TABLES ... FOR EXPORTis run,InnoDBproduces a.cfgmetadata file for the table's tablespace files in the same database directory as the table. The.cfgfiles contain metadata used for schema verification when importing tablespace files.FLUSH TABLES ... FOR EXPORTcan only be run on the table, not on individual table partitions.Copy the
.ibdand.cfgfiles from the source server database directory to the destination server database directory. In this example, only the.ibdand.cfgfiles for partition 2 (p2) and partition 3 (p3) are copied to thedatadirectory on the destination server. Partition 0 (p0) and partition 1 (p1) remain on the source server.shell> scp t1#P#p2.ibd t1#P#p2.cfg t1#P#p3.ibd t1#P#p3.cfg destination-server:
/path/to/datadir/testNoteThe
.ibdfiles and.cfgfiles must be copied before releasing the shared locks, as described in the next step.On the source server, use
UNLOCK TABLESto release the locks acquired byFLUSH TABLES ... FOR EXPORT:mysql> use test; mysql> UNLOCK TABLES;
On the destination server, import the tablespace partitions (p2 and p3):
mysql> use test; mysql> ALTER TABLE t1 IMPORT PARTITION p2, p3 TABLESPACE;
NoteWhen
ALTER TABLE ... IMPORT PARTITION ... TABLESPACEis run on subpartitioned tables, both partition and subpartition table names are allowed. When a partition name is specified, subpartitions of that partition are included in the operation.