The FILES
table provides information
about the files in which MySQL tablespace data is stored.
The FILES
table provides information
about InnoDB
data files. In NDB Cluster, this
table also provides information about the files in which NDB
Cluster Disk Data tables are stored. For additional information
specific to InnoDB
, see
InnoDB Notes, later in this section;
for additional information specific to NDB Cluster, see
NDB Notes.
The FILES
table has these columns:
FILE_ID
For
InnoDB
: The tablespace ID, also referred to as thespace_id
orfil_space_t::id
.For
NDB
: A file identifier.FILE_ID
column values are auto-generated.FILE_NAME
For
InnoDB
: The name of the data file. File-per-table and general tablespaces have an.ibd
file name extension. Undo tablespaces are prefixed byundo
. The system tablespace is prefixed byibdata
. Temporary tablespaces are prefixed byibtmp
. The file name includes the file path, which may be relative to the MySQL data directory (the value of thedatadir
system variable).For
NDB
: The name of anUNDO
log file created byCREATE LOGFILE GROUP
orALTER LOGFILE GROUP
, or of a data file created byCREATE TABLESPACE
orALTER TABLESPACE
.FILE_TYPE
For
InnoDB
: The tablespace file type. There are three possible file types forInnoDB
files.TABLESPACE
is the file type for any system, general, or file-per-table tablespace file that holds tables, indexes, or other forms of user data.TEMPORARY
is the file type for temporary tablespaces.UNDO LOG
is the file type for undo tablespaces, which hold undo records.For
NDB
: One of the valuesUNDO LOG
,DATAFILE
, orTABLESPACE
.TABLESPACE_NAME
The name of the tablespace with which the file is associated.
TABLE_CATALOG
This value is always empty.
TABLE_SCHEMA
This is always
NULL
.TABLE_NAME
This is always
NULL
.LOGFILE_GROUP_NAME
For
InnoDB
: This is alwaysNULL
.For
NDB
: The name of the log file group to which the log file or data file belongs.LOGFILE_GROUP_NUMBER
For
InnoDB
: This is alwaysNULL
.For
NDB
: For a Disk Data undo log file, the auto-generated ID number of the log file group to which the log file belongs. This is the same as the value shown for theid
column in thendbinfo.dict_obj_info
table and thelog_id
column in thendbinfo.logspaces
andndbinfo.logspaces
tables for this undo log file.ENGINE
For
InnoDB
: This is alwaysInnoDB
.For
NDB
: This is alwaysndbcluster
.FULLTEXT_KEYS
This is always
NULL
.DELETED_ROWS
This is always
NULL
.UPDATE_COUNT
This is always
NULL
.FREE_EXTENTS
For
InnoDB
: The number of fully free extents in the current data file.For
NDB
: The number of extents which have not yet been used by the file.TOTAL_EXTENTS
For
InnoDB
: The number of full extents used in the current data file. Any partial extent at the end of the file is not counted.For
NDB
: The total number of extents allocated to the file.EXTENT_SIZE
For
InnoDB
: Extent size is 1048576 (1MB) for files with a 4KB, 8KB, or 16KB page size. Extent size is 2097152 bytes (2MB) for files with a 32KB page size, and 4194304 (4MB) for files with a 64KB page size.FILES
does not reportInnoDB
page size. Page size is defined by theinnodb_page_size
system variable. Extent size information can also be retrieved from theINNODB_SYS_TABLESPACES
table whereFILES.FILE_ID = INNODB_SYS_TABLESPACES.SPACE
.For
NDB
: The size of an extent for the file in bytes.INITIAL_SIZE
For
InnoDB
: The initial size of the file in bytes.For
NDB
: The size of the file in bytes. This is the same value that was used in theINITIAL_SIZE
clause of theCREATE LOGFILE GROUP
,ALTER LOGFILE GROUP
,CREATE TABLESPACE
, orALTER TABLESPACE
statement used to create the file.MAXIMUM_SIZE
For
InnoDB
: The maximum number of bytes permitted in the file. The value isNULL
for all data files except for predefined system tablespace data files. Maximum system tablespace file size is defined byinnodb_data_file_path
. Maximum temporary tablespace file size is defined byinnodb_temp_data_file_path
. ANULL
value for a predefined system tablespace data file indicates that a file size limit was not defined explicitly.For
NDB
: This value is always the same as theINITIAL_SIZE
value.AUTOEXTEND_SIZE
The auto-extend size of the tablespace. For
NDB
,AUTOEXTEND_SIZE
is alwaysNULL
.CREATION_TIME
This is always
NULL
.LAST_UPDATE_TIME
This is always
NULL
.LAST_ACCESS_TIME
This is always
NULL
.RECOVER_TIME
This is always
NULL
.TRANSACTION_COUNTER
This is always
NULL
.VERSION
For
InnoDB
: This is alwaysNULL
.For
NDB
: The version number of the file.ROW_FORMAT
For
InnoDB
: This is alwaysNULL
.For
NDB
: One ofFIXED
orDYNAMIC
.TABLE_ROWS
This is always
NULL
.AVG_ROW_LENGTH
This is always
NULL
.DATA_LENGTH
This is always
NULL
.MAX_DATA_LENGTH
This is always
NULL
.INDEX_LENGTH
This is always
NULL
.DATA_FREE
For
InnoDB
: The total amount of free space (in bytes) for the entire tablespace. Predefined system tablespaces, which include the system tablespace and temporary table tablespaces, may have one or more data files.For
NDB
: This is alwaysNULL
.CREATE_TIME
This is always
NULL
.UPDATE_TIME
This is always
NULL
.CHECK_TIME
This is always
NULL
.CHECKSUM
This is always
NULL
.STATUS
For
InnoDB
: This value isNORMAL
by default.InnoDB
file-per-table tablespaces may reportIMPORTING
, which indicates that the tablespace is not yet available.For
NDB
: This is alwaysNORMAL
.EXTRA
For
InnoDB
: This is alwaysNULL
.For
NDB
: This column shows which data node the data file or undo log file belongs to (each data node having its own copy of each file); for an undo log files, it also shows the size of the undo log buffer. Suppose that you use this statement on an NDB Cluster with four data nodes:CREATE LOGFILE GROUP mygroup ADD UNDOFILE 'new_undo.dat' INITIAL_SIZE 2G ENGINE NDB;
After running the
CREATE LOGFILE GROUP
statement successfully, you should see a result similar to the one shown here for this query against theFILES
table:mysql> SELECT LOGFILE_GROUP_NAME, FILE_TYPE, EXTRA FROM INFORMATION_SCHEMA.FILES WHERE FILE_NAME = 'new_undo.dat'; +--------------------+-----------+-----------------------------------------+ | LOGFILE_GROUP_NAME | FILE_TYPE | EXTRA | +--------------------+-----------+-----------------------------------------+ | mygroup | UNDO LOG | CLUSTER_NODE=5;UNDO_BUFFER_SIZE=8388608 | | mygroup | UNDO LOG | CLUSTER_NODE=6;UNDO_BUFFER_SIZE=8388608 | | mygroup | UNDO LOG | CLUSTER_NODE=7;UNDO_BUFFER_SIZE=8388608 | | mygroup | UNDO LOG | CLUSTER_NODE=8;UNDO_BUFFER_SIZE=8388608 | +--------------------+-----------+-----------------------------------------+
FILES
is a nonstandardINFORMATION_SCHEMA
table.
The following notes apply to InnoDB
data
files.
Data reported by
FILES
is reported from theInnoDB
in-memory cache for open files. By comparison,INNODB_SYS_DATAFILES
reports data from theInnoDB
SYS_DATAFILES
internal data dictionary table.The data reported by
FILES
includes temporary tablespace data. This data is not available in theInnoDB
SYS_DATAFILES
internal data dictionary table, and is therefore not reported byINNODB_SYS_DATAFILES
.Undo tablespace data is reported by
FILES
.The following query returns all data pertinent to
InnoDB
tablespaces.SELECT FILE_ID, FILE_NAME, FILE_TYPE, TABLESPACE_NAME, FREE_EXTENTS, TOTAL_EXTENTS, EXTENT_SIZE, INITIAL_SIZE, MAXIMUM_SIZE, AUTOEXTEND_SIZE, DATA_FREE, STATUS FROM INFORMATION_SCHEMA.FILES WHERE ENGINE='InnoDB'\G
The
FILES
table provides information about Disk Data files only; you cannot use it for determining disk space allocation or availability for individualNDB
tables. However, it is possible to see how much space is allocated for eachNDB
table having data stored on disk—as well as how much remains available for storage of data on disk for that table—using ndb_desc.The
CREATION_TIME
,LAST_UPDATE_TIME
, andLAST_ACCESSED
values are as reported by the operating system, and are not supplied by theNDB
storage engine. Where no value is provided by the operating system, these columns displayNULL
.The difference between the
TOTAL EXTENTS
andFREE_EXTENTS
columns is the number of extents currently in use by the file:SELECT TOTAL_EXTENTS - FREE_EXTENTS AS extents_used FROM INFORMATION_SCHEMA.FILES WHERE FILE_NAME = 'myfile.dat';
To approximate the amount of disk space in use by the file, multiply that difference by the value of the
EXTENT_SIZE
column, which gives the size of an extent for the file in bytes:SELECT (TOTAL_EXTENTS - FREE_EXTENTS) * EXTENT_SIZE AS bytes_used FROM INFORMATION_SCHEMA.FILES WHERE FILE_NAME = 'myfile.dat';
Similarly, you can estimate the amount of space that remains available in a given file by multiplying
FREE_EXTENTS
byEXTENT_SIZE
:SELECT FREE_EXTENTS * EXTENT_SIZE AS bytes_free FROM INFORMATION_SCHEMA.FILES WHERE FILE_NAME = 'myfile.dat';
ImportantThe byte values produced by the preceding queries are approximations only, and their precision is inversely proportional to the value of
EXTENT_SIZE
. That is, the largerEXTENT_SIZE
becomes, the less accurate the approximations are.It is also important to remember that once an extent is used, it cannot be freed again without dropping the data file of which it is a part. This means that deletes from a Disk Data table do not release disk space.
The extent size can be set in a
CREATE TABLESPACE
statement. For more information, see CREATE TABLESPACE Statement.An additional row is present in the
FILES
table following the creation of a logfile group. This row hasNULL
for the value of theFILE_NAME
column and0
for the value of theFILE_ID
column; the value of theFILE_TYPE
column is alwaysUNDO LOG
, and that of theSTATUS
column is alwaysNORMAL
. The value of theENGINE
column for this row is alwaysndbcluster
.The
FREE_EXTENTS
column in this row shows the total number of free extents available to all undo files belonging to a given log file group whose name and number are shown in theLOGFILE_GROUP_NAME
andLOGFILE_GROUP_NUMBER
columns, respectively.Suppose there are no existing log file groups on your NDB Cluster, and you create one using the following statement:
mysql> CREATE LOGFILE GROUP lg1 ADD UNDOFILE 'undofile.dat' INITIAL_SIZE = 16M UNDO_BUFFER_SIZE = 1M ENGINE = NDB;
You can now see this
NULL
row when you query theFILES
table:mysql> SELECT DISTINCT FILE_NAME AS File, FREE_EXTENTS AS Free, TOTAL_EXTENTS AS Total, EXTENT_SIZE AS Size, INITIAL_SIZE AS Initial FROM INFORMATION_SCHEMA.FILES; +--------------+---------+---------+------+----------+ | File | Free | Total | Size | Initial | +--------------+---------+---------+------+----------+ | undofile.dat | NULL | 4194304 | 4 | 16777216 | | NULL | 4184068 | NULL | 4 | NULL | +--------------+---------+---------+------+----------+
The total number of free extents available for undo logging is always somewhat less than the sum of the
TOTAL_EXTENTS
column values for all undo files in the log file group due to overhead required for maintaining the undo files. This can be seen by adding a second undo file to the log file group, then repeating the previous query against theFILES
table:mysql> ALTER LOGFILE GROUP lg1 ADD UNDOFILE 'undofile02.dat' INITIAL_SIZE = 4M ENGINE = NDB; mysql> SELECT DISTINCT FILE_NAME AS File, FREE_EXTENTS AS Free, TOTAL_EXTENTS AS Total, EXTENT_SIZE AS Size, INITIAL_SIZE AS Initial FROM INFORMATION_SCHEMA.FILES; +----------------+---------+---------+------+----------+ | File | Free | Total | Size | Initial | +----------------+---------+---------+------+----------+ | undofile.dat | NULL | 4194304 | 4 | 16777216 | | undofile02.dat | NULL | 1048576 | 4 | 4194304 | | NULL | 5223944 | NULL | 4 | NULL | +----------------+---------+---------+------+----------+
The amount of free space in bytes which is available for undo logging by Disk Data tables using this log file group can be approximated by multiplying the number of free extents by the initial size:
mysql> SELECT FREE_EXTENTS AS 'Free Extents', FREE_EXTENTS * EXTENT_SIZE AS 'Free Bytes' FROM INFORMATION_SCHEMA.FILES WHERE LOGFILE_GROUP_NAME = 'lg1' AND FILE_NAME IS NULL; +--------------+------------+ | Free Extents | Free Bytes | +--------------+------------+ | 5223944 | 20895776 | +--------------+------------+
If you create an NDB Cluster Disk Data table and then insert some rows into it, you can see approximately how much space remains for undo logging afterward, for example:
mysql> CREATE TABLESPACE ts1 ADD DATAFILE 'data1.dat' USE LOGFILE GROUP lg1 INITIAL_SIZE 512M ENGINE = NDB; mysql> CREATE TABLE dd ( c1 INT NOT NULL PRIMARY KEY, c2 INT, c3 DATE ) TABLESPACE ts1 STORAGE DISK ENGINE = NDB; mysql> INSERT INTO dd VALUES (NULL, 1234567890, '2007-02-02'), (NULL, 1126789005, '2007-02-03'), (NULL, 1357924680, '2007-02-04'), (NULL, 1642097531, '2007-02-05'); mysql> SELECT FREE_EXTENTS AS 'Free Extents', FREE_EXTENTS * EXTENT_SIZE AS 'Free Bytes' FROM INFORMATION_SCHEMA.FILES WHERE LOGFILE_GROUP_NAME = 'lg1' AND FILE_NAME IS NULL; +--------------+------------+ | Free Extents | Free Bytes | +--------------+------------+ | 5207565 | 20830260 | +--------------+------------+
An additional row is present in the
FILES
table for any NDB Cluster tablespace, whether or not any data files are associated with the tablespace. This row hasNULL
for the value of theFILE_NAME
column, and the value of theFILE_ID
column is always0
. The value shown in theFILE_TYPE
column is alwaysTABLESPACE
, and that of theSTATUS
column is alwaysNORMAL
. The value of theENGINE
column for this row is alwaysndbcluster
.For additional information, and examples of creating and dropping NDB Cluster Disk Data objects, see NDB Cluster Disk Data Tables.
As of MySQL 5.7.31, you must have the
PROCESS
privilege to query this table.