10bet网址
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr)- 41.9Mb
PDF (A4)- 42.0Mb
Man Pages (TGZ)- 266.1Kb
Man Pages (Zip)- 376.0Kb
Info (Gzip)- 4.0Mb
Info (Zip)- 4.0Mb
Excerpts from this Manual

15.6.3.2 File-Per-Table Tablespaces

一个file-per-table tablespace contains data and indexes for a singleInnoDBtable, and is stored on the file system in a single data file.

File-per-table tablespace characteristics are described under the following topics in this section:

File-Per-Table Tablespace Configuration

InnoDBcreates tables in file-per-table tablespaces by default. This behavior is controlled by theinnodb_file_per_tablevariable. Disablinginnodb_file_per_tablecausesInnoDBto create tables in the system tablespace.

一个ninnodb_file_per_tablesetting can be specified in an option file or configured at runtime using aSET GLOBALstatement. Changing the setting at runtime requires privileges sufficient to set global system variables. SeeSection 5.1.9.1, “System Variable Privileges”.

Option file:

[mysqld] innodb_file_per_table=ON

UsingSET GLOBALat runtime:

mysql> SET GLOBAL innodb_file_per_table=ON;
File-Per-Table Tablespace Data Files

一个file-per-table tablespace is created in an.idbdata file in a schema directory under the MySQL data directory. The.ibdfile is named for the table (table_name.ibd). For example, the data file for tabletest.t1is created in thetestdirectory under the MySQL data directory:

mysql> USE test; mysql> CREATE TABLE t1 ( id INT PRIMARY KEY AUTO_INCREMENT, name VARCHAR(100) ) ENGINE = InnoDB; $> cd /path/to/mysql/data/test $> ls t1.ibd

You can use theDATA DIRECTORYclause of theCREATE TABLEstatement to implicitly create a file-per-table tablespace data file outside of the data directory. For more information, seeSection 15.6.1.2, “Creating Tables Externally”.

File-Per-Table Tablespace Advantages

File-per-table tablespaces have the following advantages over shared tablespaces such as the system tablespace or general tablespaces.

  • Disk space is returned to the operating system after truncating or dropping a table created in a file-per-table tablespace. Truncating or dropping a table stored in a shared tablespace creates free space within the shared tablespace data file, which can only be used forInnoDBdata. In other words, a shared tablespace data file does not shrink in size after a table is truncated or dropped.

  • 一个table-copying一个LTER TABLEoperation on a table that resides in a shared tablespace can increase the amount of disk space occupied by the tablespace. Such operations may require as much additional space as the data in the table plus indexes. This space is not released back to the operating system as it is for file-per-table tablespaces.

  • TRUNCATE TABLEperformance is better when executed on tables that reside in file-per-table tablespaces.

  • File-per-table tablespace data files can be created on separate storage devices for I/O optimization, space management, or backup purposes. SeeSection 15.6.1.2, “Creating Tables Externally”.

  • You can import a table that resides in file-per-table tablespace from another MySQL instance. SeeSection 15.6.1.3, “Importing InnoDB Tables”.

  • Tables created in file-per-table tablespaces support features associated withDYNAMICandCOMPRESSEDrow formats, which are not supported by the system tablespace. SeeSection 15.10, “InnoDB Row Formats”.

  • Tables stored in individual tablespace data files can save time and improve chances for a successful recovery when data corruption occurs, when backups or binary logs are unavailable, or when the MySQL server instance cannot be restarted.

  • Tables created in file-per-table tablespaces can be backed up or restored quickly using MySQL Enterprise Backup, without interrupting the use of otherInnoDBtables. This is beneficial for tables on varying backup schedules or that require backup less frequently. SeeMaking a Partial Backupfor details.

  • File-per-table tablespaces permit monitoring table size on the file system by monitoring the size of the tablespace data file.

  • Common Linux file systems do not permit concurrent writes to a single file such as a shared tablespace data file wheninnodb_flush_methodis set toO_DIRECT. As a result, there are possible performance improvements when using file-per-table tablespaces in conjunction with this setting.

  • Tables in a shared tablespace are limited in size by the 64TB tablespace size limit. By comparison, each file-per-table tablespace has a 64TB size limit, which provides plenty of room for individual tables to grow in size.

File-Per-Table Tablespace Disadvantages

File-per-table表空间有以下disadvantages compared to shared tablespaces such as the system tablespace or general tablespaces.

  • With file-per-table tablespaces, each table may have unused space that can only be utilized by rows of the same table, which can lead to wasted space if not properly managed.

  • fsyncoperations are performed on multiple file-per-table data files instead of a single shared tablespace data file. Becausefsyncoperations are per file, write operations for multiple tables cannot be combined, which can result in a higher total number offsyncoperations.

  • mysqldmust keep an open file handle for each file-per-table tablespace, which may impact performance if you have numerous tables in file-per-table tablespaces.

  • More file descriptors are required when each table has its own data file.

  • There is potential for more fragmentation, which can impedeDROP TABLEand table scan performance. However, if fragmentation is managed, file-per-table tablespaces can improve performance for these operations.

  • The buffer pool is scanned when dropping a table that resides in a file-per-table tablespace, which can take several seconds for large buffer pools. The scan is performed with a broad internal lock, which may delay other operations.

  • Theinnodb_autoextend_incrementvariable, which defines the increment size 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. Initial file-per-table tablespace extensions are by small amounts, after which extensions occur in increments of 4MB.