MySQL :: MySQL 8.4 Reference Manual :: 17.6.1.3 Importing InnoDB Tables (original) (raw)

17.6.1.3 Importing InnoDB Tables

This section describes how to import tables using the_Transportable Tablespaces_ feature, which permits importing tables, partitioned tables, or individual table partitions that reside in file-per-table tablespaces. There are many reasons why you might want to import tables:

The Transportable Tablespaces feature is described under the following topics in this section:

Prerequisites
Importing Tables

This example demonstrates how to import a regular non-partitioned table that resides in a file-per-table tablespace.

  1. On the destination instance, create a table with the same definition as the table you intend to import. (You can obtain the table definition using SHOW CREATE TABLE syntax.) If the table definition does not match, a schema mismatch error is reported when you attempt the import operation.
mysql> USE test;  
mysql> CREATE TABLE t1 (c1 INT) ENGINE=INNODB;  
  1. On the destination instance, discard the tablespace of the table that you just created. (Before importing, you must discard the tablespace of the receiving table.)
mysql> ALTER TABLE t1 DISCARD TABLESPACE;  
  1. On the source instance, runFLUSH TABLES ... FOR EXPORT to quiesce the table you intend to import. When a table is quiesced, only read-only transactions are permitted on the table.
mysql> USE test;  
mysql> FLUSH TABLES t1 FOR EXPORT;  

FLUSH TABLES ... FOR EXPORT ensures that changes to the named table are flushed to disk so that a binary table copy can be made while the server is running. WhenFLUSH TABLES ... FOR EXPORT is run,InnoDB generates a.cfg metadata file in the schema directory of the table. The .cfg file contains metadata that is used for schema verification during the import operation.
Note
The connection executingFLUSH TABLES ... FOR EXPORT must remain open while the operation is running; otherwise, the.cfg file is removed as locks are released upon connection closure. 4. Copy the .ibd file and.cfg metadata file from the source instance to the destination instance. For example:

$> scp /path/to/datadir/test/t1.{ibd,cfg} destination-server:/path/to/datadir/test  

The .ibd file and.cfg file must be copied before releasing the shared locks, as described in the next step.
Note
If you are importing a table from an encrypted tablespace,InnoDB generates a.cfp file in addition to a.cfg metadata file. The.cfp file must be copied to the destination instance together with the.cfg file. The.cfp file contains a transfer key and an encrypted tablespace key. On import,InnoDB uses the transfer key to decrypt the tablespace key. For related information, seeSection 17.13, “InnoDB Data-at-Rest Encryption”. 5. On the source instance, useUNLOCK TABLES to release the locks acquired by theFLUSH TABLES ... FOR EXPORT statement:

mysql> USE test;  
mysql> UNLOCK TABLES;  

The UNLOCK TABLES operation also removes the.cfg file. 6. On the destination instance, import the tablespace:

mysql> USE test;  
mysql> ALTER TABLE t1 IMPORT TABLESPACE;  
Importing Partitioned Tables

This example demonstrates how to import a partitioned table, where each table partition resides in a file-per-table tablespace.

  1. On the destination instance, create a partitioned table with the same definition as the partitioned table that you want to import. (You can obtain the table definition usingSHOW CREATE TABLE syntax.) If the table definition does not match, a schema mismatch error is reported when you attempt the import operation.
mysql> USE test;  
mysql> CREATE TABLE t1 (i int) ENGINE = InnoDB PARTITION BY KEY (i) PARTITIONS 3;  

In the/_`datadir`_/test directory, there is a tablespace .ibd file for each of the three partitions.

mysql> \! ls /path/to/datadir/test/  
t1#p#p0.ibd  t1#p#p1.ibd  t1#p#p2.ibd  
  1. On the destination instance, discard the tablespace for the partitioned table. (Before the import operation, you must discard the tablespace of the receiving table.)
mysql> ALTER TABLE t1 DISCARD TABLESPACE;  

The three tablespace .ibd files of the partitioned table are discarded from the/_`datadir`_/test directory. 3. On the source instance, runFLUSH TABLES ... FOR EXPORT to quiesce the partitioned table that you intend to import. When a table is quiesced, only read-only transactions are permitted on the table.

mysql> USE test;  
mysql> FLUSH TABLES t1 FOR EXPORT;  

FLUSH TABLES ... FOR EXPORT ensures that changes to the named table are flushed to disk so that binary table copy can be made while the server is running. WhenFLUSH TABLES ... FOR EXPORT is run,InnoDB generates.cfg metadata files in the schema directory of the table for each of the table's tablespace files.

mysql> \! ls /path/to/datadir/test/  
t1#p#p0.ibd  t1#p#p1.ibd  t1#p#p2.ibd  
t1#p#p0.cfg  t1#p#p1.cfg  t1#p#p2.cfg  

The .cfg files contain metadata that is used for schema verification when importing the tablespace.FLUSH TABLES ... FOR EXPORT can only be run on the table, not on individual table partitions. 4. Copy the .ibd and.cfg files from the source instance schema directory to the destination instance schema directory. For example:

$>scp /path/to/datadir/test/t1*.{ibd,cfg} destination-server:/path/to/datadir/test  

The .ibd and .cfg files must be copied before releasing the shared locks, as described in the next step.
Note
If you are importing a table from an encrypted tablespace,InnoDB generates a.cfp files in addition to a.cfg metadata files. The.cfp files must be copied to the destination instance together with the.cfg files. The.cfp files contain a transfer key and an encrypted tablespace key. On import,InnoDB uses the transfer key to decrypt the tablespace key. For related information, seeSection 17.13, “InnoDB Data-at-Rest Encryption”. 5. On the source instance, useUNLOCK TABLES to release the locks acquired byFLUSH TABLES ... FOR EXPORT:

mysql> USE test;  
mysql> UNLOCK TABLES;  
  1. On the destination instance, import the tablespace of the partitioned table:
mysql> USE test;  
mysql> ALTER TABLE t1 IMPORT TABLESPACE;  
Importing Table Partitions

This example demonstrates how to import individual table partitions, where each partition resides in a file-per-table tablespace file.

In the following example, two partitions (p2 and p3) of a four-partition table are imported.

  1. On the destination instance, create a partitioned table with the same definition as the partitioned table that you want to import partitions from. (You can obtain the table definition using SHOW CREATE TABLE syntax.) If the table definition does not match, a schema mismatch error is reported when you attempt the import operation.
mysql> USE test;  
mysql> CREATE TABLE t1 (i int) ENGINE = InnoDB PARTITION BY KEY (i) PARTITIONS 4;  

In the/_`datadir`_/test directory, there is a tablespace .ibd file for each of the four partitions.

mysql> \! ls /path/to/datadir/test/  
t1#p#p0.ibd  t1#p#p1.ibd  t1#p#p2.ibd t1#p#p3.ibd  
  1. On the destination instance, discard the partitions that you intend to import from the source instance. (Before importing partitions, you must discard the corresponding partitions from the receiving partitioned table.)
mysql> ALTER TABLE t1 DISCARD PARTITION p2, p3 TABLESPACE;  

The tablespace .ibd files for the two discarded partitions are removed from the/_`datadir`_/test directory on the destination instance, leaving the following files:

mysql> \! ls /path/to/datadir/test/  
t1#p#p0.ibd  t1#p#p1.ibd  

Note
When ALTER TABLE ... DISCARD PARTITION ... TABLESPACE is run on subpartitioned tables, both partition and subpartition table names are permitted. When a partition name is specified, subpartitions of that partition are included in the operation. 3. On the source instance, runFLUSH TABLES ... FOR EXPORT to quiesce the partitioned table. When a table is quiesced, only read-only transactions are permitted on the table.

mysql> USE test;  
mysql> FLUSH TABLES t1 FOR EXPORT;  

FLUSH TABLES ... FOR EXPORT ensures that changes to the named table are flushed to disk so that binary table copy can be made while the instance is running. WhenFLUSH TABLES ... FOR EXPORT is run,InnoDB generates a.cfg metadata file for each of the table's tablespace files in the schema directory of the table.

mysql> \! ls /path/to/datadir/test/  
t1#p#p0.ibd  t1#p#p1.ibd  t1#p#p2.ibd t1#p#p3.ibd  
t1#p#p0.cfg  t1#p#p1.cfg  t1#p#p2.cfg t1#p#p3.cfg  

The .cfg files contain metadata that used for schema verification during the import operation.FLUSH TABLES ... FOR EXPORT can only be run on the table, not on individual table partitions. 4. Copy the .ibd and.cfg files for partitionp2 and partition p3 from the source instance schema directory to the destination instance schema directory.

$> scp t1#p#p2.ibd t1#p#p2.cfg t1#p#p3.ibd t1#p#p3.cfg destination-server:/path/to/datadir/test  

The .ibd and .cfg files must be copied before releasing the shared locks, as described in the next step.
Note
If you are importing partitions from an encrypted tablespace, InnoDB generates a.cfp files in addition to a.cfg metadata files. The.cfp files must be copied to the destination instance together with the.cfg files. The.cfp files contain a transfer key and an encrypted tablespace key. On import,InnoDB uses the transfer key to decrypt the tablespace key. For related information, seeSection 17.13, “InnoDB Data-at-Rest Encryption”. 5. On the source instance, useUNLOCK TABLES to release the locks acquired byFLUSH TABLES ... FOR EXPORT:

mysql> USE test;  
mysql> UNLOCK TABLES;  
  1. On the destination instance, import table partitionsp2 and p3:
mysql> USE test;  
mysql> ALTER TABLE t1 IMPORT PARTITION p2, p3 TABLESPACE;  

Note
When ALTER TABLE ... IMPORT PARTITION ... TABLESPACE is run on subpartitioned tables, both partition and subpartition table names are permitted. When a partition name is specified, subpartitions of that partition are included in the operation.

Limitations
Usage Notes
Message: InnoDB: IO Read error: (2, No such file or directory) Error opening '.\  
test\t.cfg', will attempt to import without schema verification  
1 row in set (0.00 sec)  

Importing a table without a .cfg metadata file should only be considered if no schema mismatches are expected and the table does not contain any instantly added or dropped columns. The ability to import without a .cfg file could be useful in crash recovery scenarios where metadata is not accessible.
Attempting to import a table with columns that were added or dropped using ALGORITHM=INSTANT without using a .cfg file can result in undefined behavior.

[mysqld]  
lower_case_table_names=1  
Internals

The following information describes internals and messages written to the error log during a table import procedure.

When ALTER TABLE ... DISCARD TABLESPACE is run on the destination instance:

WhenFLUSH TABLES ... FOR EXPORT is run on the source instance:

Expected error log messages for this operation:

[Note] InnoDB: Sync to disk of '"test"."t1"' started.
[Note] InnoDB: Stopping purge
[Note] InnoDB: Writing table metadata to './test/t1.cfg'
[Note] InnoDB: Table '"test"."t1"' flushed to disk

When UNLOCK TABLES is run on the source instance:

Expected error log messages for this operation:

[Note] InnoDB: Deleting the meta-data file './test/t1.cfg'
[Note] InnoDB: Resuming purge

When ALTER TABLE ... IMPORT TABLESPACE is run on the destination instance, the import algorithm performs the following operations for each tablespace being imported:

Expected error log messages for this operation:

[Note] InnoDB: Importing tablespace for table 'test/t1' that was exported
from host 'host_name'
[Note] InnoDB: Phase I - Update all pages
[Note] InnoDB: Sync to disk
[Note] InnoDB: Sync to disk - done!
[Note] InnoDB: Phase III - Flush changes to disk
[Note] InnoDB: Phase IV - Flush complete

Note

You may also receive a warning that a tablespace is discarded (if you discarded the tablespace for the destination table) and a message stating that statistics could not be calculated due to a missing .ibd file:

[Warning] InnoDB: Table "test"."t1" tablespace is set as discarded.
7f34d9a37700 InnoDB: cannot calculate statistics for table
"test"."t1" because the .ibd file is missing. For help, please refer to
http://dev.mysql.com/doc/refman/en/innodb-troubleshooting.html