Compressed tables can be created in file-per-table tablespaces or in general tablespaces. Table compression is not available for the InnoDB system tablespace. The system tablespace (space 0, the .ibdata files) can contain user-created tables, but it also contains internal system data, which is never compressed. Thus, compression applies only to tables (and indexes) stored in file-per-table or general tablespaces.
Creating a Compressed Table in File-Per-Table Tablespace
To create a compressed table in a file-per-table tablespace,
innodb_file_per_table
must be
enabled (the default in MySQL 5.6.6) and
innodb_file_format
must be set
to Barracuda
. You can set these parameters in
the MySQL configuration file (my.cnf
or
my.ini
) or dynamically, using a
SET
statement.
After the innodb_file_per_table
and innodb_file_format
options
are configured, specify the
ROW_FORMAT=COMPRESSED
clause or
KEY_BLOCK_SIZE
clause, or both, in a
CREATE TABLE
or
ALTER TABLE
statement to create a
compressed table in a file-per-table tablespace.
For example, you might use the following statements:
SET GLOBAL innodb_file_per_table=1;
SET GLOBAL innodb_file_format=Barracuda;
CREATE TABLE t1
(c1 INT PRIMARY KEY)
ROW_FORMAT=COMPRESSED
KEY_BLOCK_SIZE=8;
Creating a Compressed Table in a General Tablespace
To create a compressed table in a general tablespace,
FILE_BLOCK_SIZE
must be defined for the
general tablespace, which is specified when the tablespace is
created. The FILE_BLOCK_SIZE
value must be a
valid compressed page size in relation to the
innodb_page_size
value, and the
page size of the compressed table, defined by the
CREATE TABLE
or
ALTER TABLE
KEY_BLOCK_SIZE
clause, must be equal to
FILE_BLOCK_SIZE/1024
. For example, if
innodb_page_size=16384
and
FILE_BLOCK_SIZE=8192
, the
KEY_BLOCK_SIZE
of the table must be 8. For
more information, see Section 14.6.3.3, “General Tablespaces”.
The following example demonstrates creating a general tablespace
and adding a compressed table. The example assumes a default
innodb_page_size
of 16K. The
FILE_BLOCK_SIZE
of 8192 requires that the
compressed table have a KEY_BLOCK_SIZE
of 8.
mysql> CREATE TABLESPACE `ts2` ADD DATAFILE 'ts2.ibd' FILE_BLOCK_SIZE = 8192 Engine=InnoDB;
mysql> CREATE TABLE t4 (c1 INT PRIMARY KEY) TABLESPACE ts2 ROW_FORMAT=COMPRESSED KEY_BLOCK_SIZE=8;
Notes
If you specify
ROW_FORMAT=COMPRESSED
, you can omitKEY_BLOCK_SIZE
; theKEY_BLOCK_SIZE
setting defaults to half theinnodb_page_size
value.If you specify a valid
KEY_BLOCK_SIZE
value, you can omitROW_FORMAT=COMPRESSED
; compression is enabled automatically.To determine the best value for
KEY_BLOCK_SIZE,
typically you create several copies of the same table with different values for this clause, then measure the size of the resulting.ibd
files and see how well each performs with a realistic workload. For general tablespaces, keep in mind that dropping a table does not reduce the size of the general tablespace.ibd
file, nor does it return disk space to the operating system. For more information, see Section 14.6.3.3, “General Tablespaces”.The
KEY_BLOCK_SIZE
value is treated as a hint; a different size could be used byInnoDB
if necessary. For file-per-table tablespaces, theKEY_BLOCK_SIZE
can only be less than or equal to theinnodb_page_size
value. If you specify a value greater than theinnodb_page_size
value, the specified value is ignored, a warning is issued, andKEY_BLOCK_SIZE
is set to half of theinnodb_page_size
value. Ifinnodb_strict_mode=ON
, specifying an invalidKEY_BLOCK_SIZE
value returns an error. For general tablespaces, validKEY_BLOCK_SIZE
values depend on theFILE_BLOCK_SIZE
setting of the tablespace. For more information, see Section 14.6.3.3, “General Tablespaces”.32KB and 64KB page sizes do not support compression. For more information, refer to the
innodb_page_size
documentation.The default uncompressed size of
InnoDB
data pages is 16KB. Depending on the combination of option values, MySQL uses a page size of 1KB, 2KB, 4KB, 8KB, or 16KB for the tablespace data file (.ibd
file). The actual compression algorithm is not affected by theKEY_BLOCK_SIZE
value; the value determines how large each compressed chunk is, which in turn affects how many rows can be packed into each compressed page.When creating a compressed table in a file-per-table tablespace, setting
KEY_BLOCK_SIZE
equal to theInnoDB
page size does not typically result in much compression. For example, settingKEY_BLOCK_SIZE=16
typically would not result in much compression, since the normalInnoDB
page size is 16KB. This setting may still be useful for tables with many longBLOB
,VARCHAR
orTEXT
columns, because such values often do compress well, and might therefore require fewer overflow pages as described in Section 14.9.1.5, “How Compression Works for InnoDB Tables”. For general tablespaces, aKEY_BLOCK_SIZE
value equal to theInnoDB
page size is not permitted. For more information, see Section 14.6.3.3, “General Tablespaces”.All indexes of a table (including the clustered index) are compressed using the same page size, as specified in the
CREATE TABLE
orALTER TABLE
statement. Table attributes such asROW_FORMAT
andKEY_BLOCK_SIZE
are not part of theCREATE INDEX
syntax forInnoDB
tables, and are ignored if they are specified (although, if specified, they appear in the output of theSHOW CREATE TABLE
statement).For performance-related configuration options, see Section 14.9.1.3, “Tuning Compression for InnoDB Tables”.
Restrictions on Compressed Tables
MySQL versions prior to 5.1 cannot process compressed tables.
Compressed tables cannot be stored in the
InnoDB
system tablespace.General tablespaces can contain multiple tables, but compressed and uncompressed tables cannot coexist within the same general tablespace.
Compression applies to an entire table and all its associated indexes, not to individual rows, despite the clause name
ROW_FORMAT
.