MySQL :: MySQL 8.4 Reference Manual :: 17.6.1.2 Creating Tables Externally (original) (raw)

17.6.1.2 Creating Tables Externally

There are different reasons for creating InnoDB tables externally; that is, creating tables outside of the data directory. Those reasons might include space management, I/O optimization, or placing tables on a storage device with particular performance or capacity characteristics, for example.

Using the DATA DIRECTORY Clause

You can create an InnoDB table in an external directory by specifying a DATA DIRECTORY clause in the CREATE TABLE statement.

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

The DATA DIRECTORY clause is supported for tables created in file-per-table tablespaces. Tables are implicitly created in file-per-table tablespaces when theinnodb_file_per_table variable is enabled, which it is by default.

mysql> SELECT @@innodb_file_per_table;
+-------------------------+
| @@innodb_file_per_table |
+-------------------------+
|                       1 |
+-------------------------+

For more information about file-per-table tablespaces, seeSection 17.6.3.2, “File-Per-Table Tablespaces”.

When you specify a DATA DIRECTORY clause in aCREATE TABLE statement, the table's data file (_`tablename`_.ibd) is created in a schema directory under the specified directory.

Tables and table partitions created outside of the data directory using the DATA DIRECTORY clause are restricted to directories known to InnoDB. This requirement permits database administrators to control where tablespace data files are created and ensures that data files can be found during recovery (seeTablespace Discovery During Crash Recovery). Known directories are those defined by thedatadir,innodb_data_home_dir, andinnodb_directories variables. You can use the following statement to check those settings:

mysql> SELECT @@datadir,@@innodb_data_home_dir,@@innodb_directories;

If the directory you want to use is unknown, add it to theinnodb_directories setting before you create the table. Theinnodb_directories variable is read-only. Configuring it requires restarting the server. For general information about setting system variables, seeSection 7.1.9, “Using System Variables”.

The following example demonstrates creating a table in an external directory using the DATA DIRECTORY clause. It is assumed that theinnodb_file_per_table variable is enabled and that the directory is known toInnoDB.

mysql> USE test;
Database changed

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

# MySQL creates the table's data file in a schema directory
# under the external directory

$> cd /external/directory/test
$> ls
t1.ibd
Usage Notes:
Using CREATE TABLE ... TABLESPACE Syntax

CREATE TABLE ... TABLESPACE syntax can be used in combination with theDATA DIRECTORY clause to create a table in an external directory. To do so, specifyinnodb_file_per_table as the tablespace name.

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

This method is supported only for tables created in file-per-table tablespaces, but does not require theinnodb_file_per_table variable to be enabled. In all other respects, this method is equivalent to the CREATE TABLE ... DATA DIRECTORY method described above. The same usage notes apply.

Creating a Table in an External General Tablespace

You can create a table in a general tablespace that resides in an external directory.