14.2.1.1 Using Per-Table Tablespaces

You can store each InnoDB table and its indexes in its own file. This feature is called multiple tablespaces because in effect each table has its own tablespace.

Advantages of Per-Table Tablespaces
Potential Disadvantages of Per-Table Tablespaces
Enabling and Disabling Multiple Tablespaces

To enable multiple tablespaces, start the server with the --innodb_file_per_table option. For example, add a line to the [mysqld] section of my.cnf:

[mysqld]
innodb_file_per_table

With multiple tablespaces enabled, InnoDB stores each newly created table into its own tbl_name.ibd file in the database directory where the table belongs. This is similar to what the MyISAM storage engine does, but MyISAM divides the table into a tbl_name.MYD data file and an tbl_name.MYI index file. For InnoDB, the data and the indexes are stored together in the .ibd file. The tbl_name.frm file is still created as usual.

You cannot freely move .ibd files between database directories as you can with MyISAM table files. This is because the table definition that is stored in the InnoDB shared tablespace includes the database name, and because InnoDB must preserve the consistency of transaction IDs and log sequence numbers.

If you remove the innodb_file_per_table line from my.cnf and restart the server, InnoDB creates tables inside the shared tablespace files again.

The --innodb_file_per_table option affects only table creation, not access to existing tables. If you start the server with this option, new tables are created using .ibd files, but you can still access tables that exist in the shared tablespace. If you start the server without this option, new tables are created in the shared tablespace, but you can still access any tables that were created using multiple tablespaces.

Note

InnoDB always needs the shared tablespace because it puts its internal data dictionary and undo logs there. The .ibd files are not sufficient for InnoDB to operate.

To move an .ibd file and the associated table from one database to another, use a RENAME TABLE statement:

RENAME TABLE db1.tbl_name TO db2.tbl_name;

If you have a clean backup of an .ibd file, you can restore it to the MySQL installation from which it originated as follows:

  1. Issue this ALTER TABLE statement to delete the current .ibd file:

    ALTER TABLE tbl_name DISCARD TABLESPACE;
    
  2. Copy the backup .ibd file to the proper database directory.

  3. Issue this ALTER TABLE statement to tell InnoDB to use the new .ibd file for the table:

    ALTER TABLE tbl_name IMPORT TABLESPACE;
    

In this context, a clean .ibd file backup is one for which the following requirements are satisfied:

You can make a clean backup .ibd file using the following method:

  1. Stop all activity from the mysqld server and commit all transactions.

  2. Wait until SHOW ENGINE INNODB STATUS shows that there are no active transactions in the database, and the main thread status of InnoDB is Waiting for server activity. Then you can make a copy of the .ibd file.

Another method for making a clean copy of an .ibd file is to use the commercial InnoDB Hot Backup tool:

  1. Use InnoDB Hot Backup to back up the InnoDB installation.

  2. Start a second mysqld server on the backup and let it clean up the .ibd files in the backup.