Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 38.1Mb
PDF (A4) - 38.1Mb
PDF (RPM) - 33.0Mb
HTML Download (TGZ) - 8.1Mb
HTML Download (Zip) - 8.1Mb
HTML Download (RPM) - 7.0Mb
Man Pages (TGZ) - 132.7Kb
Man Pages (Zip) - 189.0Kb
Info (Gzip) - 3.4Mb
Info (Zip) - 3.4Mb
Excerpts from this Manual

MySQL 8.0 Reference Manual  /  ...  /  Creating File-Per-Table Tablespaces Outside the Data Directory

15.7.5 Creating File-Per-Table Tablespaces Outside the Data Directory

To create a file-per-table tablespace in a location outside the MySQL data directory, use the DATA DIRECTORY = absolute_path_to_directory clause of the CREATE TABLE statement.

Plan the location in advance, because you cannot use the DATA DIRECTORY clause with the ALTER TABLE statement to change the location later. The directory you specify could be on another storage device with particular performance or capacity characteristics, such as a fast SSD or a high-capacity HDD.

Within the target directory, MySQL creates a subdirectory corresponding to the database name, and within that, a .ibd file for the new table.

The following example demonstrates creating a file-per-table tablespace outside the MySQL data directory and shows the .ibd file created in the specified directory.

mysql> USE test;
Database changed

mysql> SHOW VARIABLES LIKE 'innodb_file_per_table';
+-----------------------+-------+
| Variable_name         | Value |
+-----------------------+-------+
| innodb_file_per_table | ON    |
+-----------------------+-------+

mysql> CREATE TABLE t1 (c1 INT PRIMARY KEY) DATA DIRECTORY = '/alternative/directory';

# MySQL creates a .ibd file for the new table in a subdirectory that corresponds
# to the database name

db_user@ubuntu:~/alternative/directory/test$ ls
t1.ibd
Note

For tablespace data files created outside of the MySQL data directory to be found during recovery, the directory must be known to InnoDB. To make a directory known, add it to the innodb_directories argument value. innodb_directories is a read-only startup option. Configuring it requires restarting the server.

You can also use CREATE TABLE ... TABLESPACE in combination with the DATA DIRECTORY clause to create a file-per-table tablespace outside the MySQL data directory. To do so, you must specify innodb_file_per_table as the tablespace name.

mysql> CREATE TABLE t2 (c1 INT PRIMARY KEY) TABLESPACE = innodb_file_per_table
       DATA DIRECTORY = '/alternative/directory';

You do not have to enable innodb_file_per_table when using this method.

Usage Notes:

  • MySQL initially holds the .ibd file open, preventing you from dismounting the device, but might eventually close the table if the server is busy. Be careful not to accidentally dismount an external device while MySQL is running, or start MySQL while the device is disconnected. Attempting to access a table when the associated .ibd file is missing causes a serious error that requires a server restart.

    A server restart issues errors and warnings if the .ibd file is not at the expected path. In this case, you can restore the tablespace .ibd file from a backup or drop the table to remove the information about it from the data dictionary.

  • Before placing tables on an NFS-mounted volume, review potential issues outlined in Using NFS with MySQL.

  • If you use an LVM snapshot, file copy, or other file-based mechanism to back up the .ibd file, always use the FLUSH TABLES ... FOR EXPORT statement first to make sure that all changes buffered in memory are flushed to disk before the backup occurs.

  • The DATA DIRECTORY clause is a supported alternative to using symbolic links, which is not supported for individual InnoDB tables.


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
Sign Up Login You must be logged in to post a comment.