All pages
Powered by GitBook
1 of 1

Loading...

InnoDB COMPRESSED Row Format

Learn about the COMPRESSED row format, which compresses data and index pages using algorithms like zlib to minimize storage footprint at the cost of CPU.

An alternative (and usually superior) way to compress InnoDB tables is by using InnoDB Page Compression. See Comparison with the COMPRESSED Row Format.

The COMPRESSED row format is similar to the COMPACT row format, but tables using the COMPRESSED row format can store even more data on overflow pages than tables using the COMPACT row format. This results in more efficient data storage than tables using the COMPACT row format, especially for tables containing columns using the VARBINARY, VARCHAR, BLOB and TEXT data types.

The COMPRESSED row format also supports compression of all data and index pages.

Supported Block Sizes

The Compressed row format supports the following block sizes:

Block Size
KEY_BLOCK_SIZE Value

If the KEY_BLOCK_SIZE table option is not specified, the block size defaults to half of . With the default 16 KB page size, the block size defaults to 8 KB.

For compression to be effective, the chosen block size should be smaller than the servers value of the system variable.

Supported Index Prefix Limits

The limit for indexing column values depends on the value:

Page Size
Index Prefix Limit

Using the COMPRESSED Row Format

The Compressed row format does not efficiently use the InnoDB buffer pool, so it is not the recommended way to achieve InnoDB table compression. For more information about how to compress InnoDB tables, see .

An InnoDB table that uses the COMPRESSED row format can be created by setting the table option to COMPRESSED and by setting the table option to one of the following values in a or statement, where the units are in KB.

16k is the default value of the system variable, so using 16 will usually result in minimal compression unless one of the following is true:

  • The table has many columns that can be stored in overflow pages, such as columns that use the , , and data types.

  • The server is using a non-default value that is greater than 16k.

The value of the system variable can be set to 32k and 64k. This is especially useful because the larger page size permits more columns using the , , and data types. Regardless, even when the value of the system variable is set to some value higher than 16k, 16 is still the maximum value for the table option for InnoDB tables using the COMPRESSED row format.

The COMPRESSED row format cannot be set as the default row format with the system variable.

The COMPRESSED row format is only supported by the Barracuda . In earlier versions, the COMPRESSED row format is only supported if the is Barracuda. Therefore, the system variable must be set to Barracuda to use these row formats in those versions.

In earlier versions, the COMPRESSED row format is also only supported if the table is in a tablespace. Therefore, the system variable must be set to ON to use this row format in those versions.

It is also recommended to set the system variable to ON when using this row format.

InnoDB automatically uses the COMPRESSED row format for a table if the table option is set to some value in a or statement:

If the table option is not set to some value, but the table option is set to COMPRESSED in a or statement, then InnoDB uses a default value of 8 for the table option:

Create an InnoDB Table with the Compressed Row Format using ROW_FORMAT

The default block size for tables that use the Compressed row format is half of . With the default 16 KB page size, the block size defaults to 8 KB. A compressed table with the default block size can be created by setting the ROW_FORMAT table option to COMPRESSED:

Step-by-Step Procedure

  1. Connect to the server using :

  1. Confirm that the default storage engine is InnoDB by checking the system variable using the statement:

  1. Create the table using the statement, and specify the Compressed row format using the ROW_FORMAT table option:

  1. Confirm that the table uses the Compressed row format with an 8 KB block size by querying the table:

Create an InnoDB Table with the Compressed Row Format using KEY_BLOCK_SIZE

The default block size for tables that use the Compressed row format is half of . With the default 16 KB page size, the block size defaults to 8 KB. A compressed table with a non-default block size can be created by setting the KEY_BLOCK_SIZE table option to the desired block size.

Step-by-Step Procedure

  1. Connect to the server using :

  1. Confirm that the default storage engine is InnoDB by checking the system variable using the statement:

  1. Create the table using the CREATE TABLE statement, and specify the block size using the KEY_BLOCK_SIZE table option, which implies the Compressed row format:

  1. Confirm that the table uses the Compressed row format with an 8 KB block size by querying the table:

Compression with the COMPRESSED Row Format

The COMPRESSED row format supports compression of all data and index pages.

To avoid compressing and uncompressing pages too many times, InnoDB tries to keep both compressed and uncompressed pages in the when there is enough room. This results in a bigger cache. When there is not enough room, an adaptive LRU algorithm is used to decide whether compressed or uncompressed pages should be evicted from the buffer: for CPU-bound workloads, the compressed pages are evicted first; for I/O-bound workloads, the uncompressed pages are evicted first. Of course, when necessary, both the compressed and uncompressed version of the same data can be evicted from the buffer.

Each compressed page has an uncompressed modification log, stored within the page itself. InnoDB writes small changes into it. When the space in the modification log runs out, the page is uncompressed, changes are applied, and the page is recompressed again. This is done to avoid some unnecessary decompression and compression operations.

Sometimes a compression failure might happen, because the data has grown too much to fit the page. When this happens, the page (and the index node) is split into two different pages. This process can be repeated recursively until the data fit the pages. This can be CPU-consuming on some busy servers which perform many write operations.

Before writing a compressed page into a data file, InnoDB writes it into the . This ensures that the can always be used to recover tables after a crash, even if the compression library is updated and some incompatibilities are introduced. But this also means that the will grow faster and might need more space, or the frequency of checkpoints might need to increase.

Monitoring Performance of the COMPRESSED Row Format

The following INFORMATION_SCHEMA tables can be used to monitor the performances of InnoDB compressed tables:

Index Prefixes with the COMPRESSED Row Format

The COMPRESSED row format supports index prefixes up to 3072 bytes. In and before, the system variable is used to configure the maximum index prefix length. In these versions, if is set to ON, then the maximum prefix length is 3072 bytes, and if it is set to OFF, then the maximum prefix length is 767 bytes.

Overflow Pages with the COMPRESSED Row Format

All InnoDB row formats can store certain kinds of data in overflow pages. This allows for the maximum row size of an InnoDB table to be larger than the maximum amount of data that can be stored in the row's main data page. See for more information about the other factors that can contribute to the maximum row size for InnoDB tables.

In the COMPRESSED row format variable-length columns, such as columns using the , , and data types, can be completely stored in overflow pages.

InnoDB only considers using overflow pages if the table's row size is greater than half of . If the row size is greater than this, then InnoDB chooses variable-length columns to be stored on overflow pages until the row size is less than half of .

For and columns, only values longer than 40 bytes are considered for storage on overflow pages. For and columns, only values longer than 255 bytes are considered for storage on overflow pages. Bytes that are stored to track a value's length do not count towards these limits. These limits are only based on the length of the actual column's data.

These limits differ from the limits for the COMPACT row format, where the limit is 767 bytes for all types.

Fixed-length columns greater than 767 bytes are encoded as variable-length columns, so they can also be stored in overflow pages if the table's row size is greater than half of . Even though a column using the data type can hold at most 255 characters, a column can still exceed 767 bytes in some cases. For example, a char(255) column can exceed 767 bytes if the is utf8mb4.

If a column is chosen to be stored on overflow pages, then the entire value of the column is stored on overflow pages, and only a 20-byte pointer to the column's first overflow page is stored on the main page. Each overflow page is the size of . If a column is too large to be stored on a single overflow page, then it is stored on multiple overflow pages. Each overflow page contains part of the data and a 20-byte pointer to the next overflow page, if a next page exists.

This behavior differs from the behavior of the COMPACT row format, which always stores the column prefix on the main page. This allows tables using the COMPRESSED row format to contain a high number of columns using the , , and data types.

Read-Only

MariaDB starting with

From until , tables that are of the COMPRESSED row format are read-only by default. This was intended to be the first step towards removing write support and deprecating the feature. This plan has been scrapped, and from , COMPRESSED tables are no longer read-only by default. From to , set the variable to OFF to make the tables writable.

See Also

This page is licensed: CC BY-SA / Gnu FDL

1 KB

1

2 KB

2

4 KB

4

8 KB

8

16 KB

16

16k

3072 bytes

8k

1536 bytes

4k

768 bytes

innodb_page_size
innodb_page_size
innodb_page_size
Configure InnoDB Page Compression
ROW_FORMAT
KEY_BLOCK_SIZE
CREATE TABLE
ALTER TABLE
innodb_page_size
VARBINARY
VARCHAR
BLOB
TEXT
innodb_page_size
innodb_page_size
VARBINARY
VARCHAR
BLOB
TEXT
innodb_page_size
KEY_BLOCK_SIZE
innodb_default_row_format
file format
InnoDB file format
innodb_file_format
file per-table
innodb_file_per_table
innodb_strict_mode
KEY_BLOCK_SIZE
CREATE TABLE
ALTER TABLE
KEY_BLOCK_SIZE
ROW_FORMAT
CREATE TABLE
ALTER TABLE
KEY_BLOCK_SIZE
innodb_page_size
MariaDB Client
default_storage_engine
SHOW SESSION VARIABLES
CREATE TABLE
information_schema.INNODB_SYS_TABLES
innodb_page_size
MariaDB Client
default_storage_engine
SHOW SESSION VARIABLES
information_schema.INNODB_SYS_TABLES
buffer pool
redo log
redo log
redo log
INNODB_CMP and INNODB_CMP_RESET
INNODB_CMP_PER_INDEX and INNODB_CMP_PER_INDEX_RESET
INNODB_CMPMEM and INNODB_CMPMEM_RESET
innodb_large_prefix
innodb_large_prefix
Maximum Row Size
VARBINARY
VARCHAR
BLOB
TEXT
innodb_page_size
innodb_page_size
BLOB
TEXT
VARBINARY
VARCHAR
innodb_page_size
CHAR
CHAR
character set
innodb_page_size
VARBINARY
VARCHAR
BLOB
TEXT
10.6
MariaDB 10.6.0
MariaDB 10.6.5
MariaDB 10.6.6
MariaDB 10.6.0
MariaDB 10.6.5
innodb_read_only_compressed
InnoDB Page Compression
Storage-Engine Independent Column Compression
SET SESSION innodb_strict_mode=ON;

SET GLOBAL innodb_file_per_table=ON;

SET GLOBAL innodb_file_format='Barracuda';

CREATE TABLE tab (
   id INT,
   str VARCHAR(50)
) ENGINE=InnoDB KEY_BLOCK_SIZE=4;
SET SESSION innodb_strict_mode=ON;

SET GLOBAL innodb_file_per_table=ON;

SET GLOBAL innodb_file_format='Barracuda';

CREATE TABLE tab (
   id INT,
   str VARCHAR(50)
) ENGINE=InnoDB ROW_FORMAT=COMPRESSED;
CREATE TABLE hq_sales.invoices (
   invoice_id BIGINT UNSIGNED AUTO_INCREMENT NOT NULL,
   branch_id INT NOT NULL,
   customer_id INT,
   invoice_date DATETIME(6),
   invoice_total DECIMAL(13, 2),
   payment_method ENUM('NONE', 'CASH', 'WIRE_TRANSFER', 'CREDIT_CARD', 'GIFT_CARD'),
   PRIMARY KEY(invoice_id)
) ROW_FORMAT = Compressed;
$ mariadb --user=root
SHOW SESSION VARIABLES
   LIKE 'default_storage_engine';
+------------------------+--------+
| Variable_name          | Value  |
+------------------------+--------+
| default_storage_engine | InnoDB |
+------------------------+--------+
CREATE TABLE hq_sales.invoices (
   invoice_id BIGINT UNSIGNED AUTO_INCREMENT NOT NULL,
   branch_id INT NOT NULL,
   customer_id INT,
   invoice_date DATETIME(6),
   invoice_total DECIMAL(13, 2),
   payment_method ENUM('NONE', 'CASH', 'WIRE_TRANSFER', 'CREDIT_CARD', 'GIFT_CARD'),
   PRIMARY KEY(invoice_id)
) ROW_FORMAT = Compressed;
SELECT NAME, ROW_FORMAT, ZIP_PAGE_SIZE
FROM information_schema.INNODB_SYS_TABLES
WHERE NAME='hq_sales/invoices';
+-------------------+------------+---------------+
| NAME              | ROW_FORMAT | ZIP_PAGE_SIZE |
+-------------------+------------+---------------+
| hq_sales/invoices | Compressed |          8192 |
+-------------------+------------+---------------+
CREATE TABLE hq_sales.invoices (
   invoice_id BIGINT UNSIGNED AUTO_INCREMENT NOT NULL,
   branch_id INT NOT NULL,
   customer_id INT,
   invoice_date DATETIME(6),
   invoice_total DECIMAL(13, 2),
   payment_method ENUM('NONE', 'CASH', 'WIRE_TRANSFER', 'CREDIT_CARD', 'GIFT_CARD'),
   PRIMARY KEY(invoice_id)
) KEY_BLOCK_SIZE = 4;
$ mariadb --user=root
SHOW SESSION VARIABLES
   LIKE 'default_storage_engine';
+------------------------+--------+
| Variable_name          | Value  |
+------------------------+--------+
| default_storage_engine | InnoDB |
+------------------------+--------+
CREATE TABLE hq_sales.invoices (
   invoice_id BIGINT UNSIGNED AUTO_INCREMENT NOT NULL,
   branch_id INT NOT NULL,
   customer_id INT,
   invoice_date DATETIME(6),
   invoice_total DECIMAL(13, 2),
   payment_method ENUM('NONE', 'CASH', 'WIRE_TRANSFER', 'CREDIT_CARD', 'GIFT_CARD'),
   PRIMARY KEY(invoice_id)
) KEY_BLOCK_SIZE = 4;
SELECT NAME, ROW_FORMAT, ZIP_PAGE_SIZE
FROM information_schema.INNODB_SYS_TABLES
WHERE NAME='hq_sales/invoices';
+-------------------+------------+---------------+
| NAME              | ROW_FORMAT | ZIP_PAGE_SIZE |
+-------------------+------------+---------------+
| hq_sales/invoices | Compressed |          4096 |
+-------------------+------------+---------------+
MariaDB 10.2