By default, all InnoDB tables and indexes are
stored in the system
tablespace. As an alternative, you can store each
InnoDB table and associated indexes in its own
data file. This feature is called “file-per-table
tablespaces” because each table has its own tablespace, and
each tablespace has its own
.ibd data
file. This feature is controlled by the
innodb_file_per_table
configuration option.
Advantages of File-Per-Table Tablespaces
You can reclaim disk space when truncating or dropping a table stored in a file-per-table tablepace. Truncating or dropping tables stored in the shared system tablespace creates free space internally in the system tablespace data files (ibdata files) which can only be used for new
InnoDBdata.Similarly, a table-copying
ALTER TABLEoperation on table that resides in a shared tablespace can increase the amount of space used by the tablespace. Such operations may require as much additional space as the data in the table plus indexes. The additional space required for the table-copyingALTER TABLEoperation is not released back to the operating system as it is for file-per-table tablespaces.The
TRUNCATE TABLEoperation is faster when run on tables stored in file-per-table tablepaces.You can store specific tables on separate storage devices, for I/O optimization, space management, or backup purposes.
You can run
OPTIMIZE TABLEto compact or recreate a file-per-table tablespace. When you run anOPTIMIZE TABLE,InnoDBcreates a new.ibdfile with a temporary name, using only the space required to store actual data. When the optimization is complete,InnoDBremoves the old.ibdfile and replaces it with the new one. If the previous.ibdfile grew significantly but the actual data only accounted for a portion of its size, runningOPTIMIZE TABLEcan reclaim the unused space.You can move individual
InnoDBtables rather than entire databases.Tables created in file-per-table tablespaces use the Barracuda file format. The Barracuda file format enables features such as compressed and dynamic row formats. Tables created in the system tablespace cannot use these features. To take advantage of these features for an existing table, enable the
innodb_file_per_tablesetting and runALTER TABLEto place the table in a file-per-table tablespace. Before converting tables, refer to Section 14.11.5, “Converting Tables from MyISAM to InnoDB”.tENGINE=INNODBYou can enable more efficient storage for tables with large
BLOBorTEXTcolumns using the dynamic row format.File-per-table tablespaces may improve chances for a successful recovery and save time when a corruption occurs, when a server cannot be restarted, or when backup and binary logs are unavailable.
You can back up or restore individual tables quickly using the MySQL Enterprise Backup product, without interrupting the use of other
InnoDBtables. This is beneficial if you have tables that require backup less frequently or on a different backup schedule. See Partial Backup and Restore Options for details.File-per-table tablespaces are convenient for per-table status reporting when copying or backing up tables.
You can monitor table size at a file system level, without accessing MySQL.
Common Linux file systems do not permit concurrent writes to a single file when
innodb_flush_methodis set toO_DIRECT. As a result, there are possible performance improvements when usinginnodb_file_per_tablein conjunction withinnodb_flush_method.The system tablespace stores the
InnoDBdata dictionary and undo logs, and has a 64TB size limit. By comparison, each file-per-table tablespace has a 64TB size limit, which provides room for growth. See Section 14.11.8, “Limits on InnoDB Tables” for related information.
Potential Disadvantages of File-Per-Table Tablespaces
With file-per-table tablespaces, each table may have unused space, which can only be utilized by rows of the same table. This could lead to wasted space if not properly managed.
fsyncoperations must run on each open table rather than on a single file. Because there is a separatefsyncoperation for each file, write operations on multiple tables cannot be combined into a single I/O operation. This may requireInnoDBto perform a higher total number offsyncoperations.mysqld must keep one open file handle per table, which may impact performance if you have numerous tables in file-per-table tablespaces.
More file descriptors are used.
If backward compatibility with MySQL 5.1 is a concern, be aware that enabling
innodb_file_per_tablemeans that anALTER TABLEoperation will move anInnoDBtable from the system tablespace to an individual.ibdfile in cases whereALTER TABLErecreates the table (ALTER OFFLINE).For example, when restructuring the clustered index for an
InnoDBtable, the table is re-created using the current setting forinnodb_file_per_table. This behavior does not apply when adding or droppingInnoDBsecondary indexes. When a secondary index is created without rebuilding the table, the index is stored in the same file as the table data, regardless of the currentinnodb_file_per_tablesetting.If many tables are growing there is potential for more fragmentation which can impede
DROP TABLEand table scan performance. However, when fragmentation is managed, having files in their own tablespace can improve performance.The buffer pool is scanned when dropping a file-per-table tablespace, which can take several seconds for buffer pools that are tens of gigabytes in size. The scan is performed with a broad internal lock, which may delay other operations. Tables in the system tablespace are not affected.
The
innodb_autoextend_incrementvariable, which defines increment size (in MB) for extending the size of an auto-extending shared tablespace file when it becomes full, does not apply to file-per-table tablespace files, which are auto-extending regardless of theinnodb_autoextend_incrementsetting. The initial extensions are by small amounts, after which extensions occur in increments of 4MB.
Enabling and Disabling File-Per-Table Tablespaces
To enable file-per-table 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=1
With innodb_file_per_table
enabled, InnoDB stores each newly created table
into its own
file
in the database directory where the table belongs. This is similar
to what the tbl_name.ibdMyISAM storage engine does, but
MyISAM divides the table into a
data
file and an
tbl_name.MYD index
file. For tbl_name.MYIInnoDB, the data and the indexes are
stored together in the .ibd file. The
file
is still created as usual.
tbl_name.frm
If you remove the
innodb_file_per_table line from
my.cnf and restart the server, newly created
InnoDB tables are created inside the shared
tablespace files again.
To move a table from the system tablespace to its own tablespace,
change the innodb_file_per_table
setting and rebuild the table:
SET GLOBAL innodb_file_per_table=1;
ALTER TABLE table_name ENGINE=InnoDB;
InnoDB requires the shared tablespace to
store its internal data dictionary and undo logs. The
.ibd files alone are not sufficient for
InnoDB to operate.
When a table is moved out of the system tablespace into its own
.ibd file, the data files that make up the
system tablespace remain the same size. The space formerly
occupied by the table can be reused for new
InnoDB data, but is not reclaimed for use by
the operating system. When moving large
InnoDB tables out of the system tablespace,
where disk space is limited, you might prefer to turn on
innodb_file_per_table and then
recreate the entire instance using the
mysqldump command.
Portability Considerations for .ibd Files
You cannot freely move .ibd files between
database directories as you can with MyISAM
table files. The table definition stored in the
InnoDB shared tablespace includes the database
name. The transaction IDs and log sequence numbers stored in the
tablespace files also differ between databases.
To move an .ibd file and the associated table
from one database to another, use a RENAME
TABLE statement:
RENAME TABLEdb1.tbl_nameTOdb2.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:
The table must not have been dropped or truncated since you copied the
.ibdfile, because doing so changes the table ID stored inside the tablespace.Issue this
ALTER TABLEstatement to delete the current.ibdfile:ALTER TABLE
tbl_nameDISCARD TABLESPACE;Copy the backup
.ibdfile to the proper database directory.Issue this
ALTER TABLEstatement to tellInnoDBto use the new.ibdfile for the table:ALTER TABLE
tbl_nameIMPORT TABLESPACE;
In this context, a “clean” .ibd
file backup is one for which the following requirements are
satisfied:
There are no uncommitted modifications by transactions in the
.ibdfile.There are no unmerged change buffer entries in the
.ibdfile.Purge has removed all delete-marked index records from the
.ibdfile.mysqld has flushed all modified pages of the
.ibdfile from the buffer pool to the file.
You can make a clean backup .ibd file using
the following method:
Stop all activity from the mysqld server and commit all transactions.
Wait until
SHOW ENGINE INNODB STATUSshows that there are no active transactions in the database, and the main thread status ofInnoDBisWaiting for server activity. Then you can make a copy of the.ibdfile.
Another method for making a clean copy of an
.ibd file is to use the MySQL Enterprise
Backup product:
Use MySQL Enterprise Backup to back up the
InnoDBinstallation.Start a second mysqld server on the backup and let it clean up the
.ibdfiles in the backup.