All pages
Powered by GitBook
1 of 1

Loading...

InnoDB DYNAMIC Row Format

The DYNAMIC row format, default in modern MariaDB versions, optimizes storage for large BLOB/TEXT columns by storing them on separate overflow pages.

DYNAMIC is the default InnoDB row format.

The DYNAMIC row format is similar to the COMPACT row format, but tables using the DYNAMIC 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. While InnoDB tables using the COMPRESSED row format can result in even greater space-efficiency, COMPRESSED requires substantially more memory and CPU to both read and write, so there is a significant performance and concurrency trade-off for that space-efficiency gain. COMPRESSED tables are not recommended for production use in most situations, while DYNAMIC row format scales well in high-performance environments.

Supported Index Prefix Limits

The limit for indexing column values depends on the value:

Page Size
Index Prefix Limit

Using the DYNAMIC Row Format

The default row format is DYNAMIC, as long as the system variable has not been modified. Therefore, in these versions, the easiest way to create an InnoDB table that uses the DYNAMIC row format is by not setting the table option at all in a or statement.

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

For example:

Create an InnoDB Table with the Dynamic Row Format by Default

InnoDB uses the Dynamic row format for new InnoDB tables by default, because the system variable is dynamic by default.

Let's create an InnoDB table after confirming that the default storage engine is InnoDB and that InnoDB's default row format is Dynamic:

  1. Connect to the server using :

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

  1. Confirm that InnoDB's default row format is Dynamic by checking the system variable using the statement:

  1. If the database does not exist, then create the database for the table using the statement:

  1. Create the table using the statement:

  1. Confirm that the table uses the Dynamic row format by querying the table:

Create an InnoDB Table with the Dynamic Row Format using ROW_FORMAT

An InnoDB table that uses the Dynamic row format can be created using the ROW_FORMAT table option.

Let's create an InnoDB table after confirming that the default storage engine is InnoDB and that InnoDB's default row format is not Dynamic:

  1. Connect to the server using :

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

  1. Confirm that InnoDB's default row format is not Dynamic by checking the system variable using the statement:

  1. If the database does not exist, then create the database for the table using the statement:

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

  1. Confirm that the table uses the Dynamic row format by querying the table:

Convert InnoDB Tables to the Dynamic Row Format

If your database was physically upgraded from some older version of MariaDB Server or MySQL, then some of your tables may not be using the Dynamic row format. If you want to get the benefits of the Dynamic row format, then those tables will need to be converted to use it.

Let's convert some InnoDB tables to the Dynamic row format:

  1. Connect to the server using MariaDB Client:

  1. Search for InnoDB tables that do not use the Dynamic row format by querying the table:

  1. Alter the table using the statement, and specify the Dynamic row format using the ROW_FORMAT table option:

  1. Confirm that the table uses the Dynamic row format by querying the table again:

Index Prefixes with the DYNAMIC Row Format

The DYNAMIC row format supports index prefixes up to 3072 bytes. In earlier versions of MariaDB, 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 DYNAMIC 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 DYNAMIC 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 DYNAMIC row format to contain a high number of columns using the , , and data types.

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

16k 32k 16k

3072 bytes

8k

1536 bytes

4k

768 bytes

innodb_page_size
innodb_default_row_format
ROW_FORMAT
CREATE TABLE
ALTER TABLE
innodb_strict_mode
innodb_default_row_format
MariaDB Client
default_storage_engine
SHOW SESSION VARIABLES
innodb_default_row_format
SHOW GLOBAL VARIABLES
CREATE DATABASE
CREATE TABLE
information_schema.INNODB_SYS_TABLES
MariaDB Client
default_storage_engine
SHOW SESSION VARIABLES
innodb_default_row_format
SHOW GLOBAL VARIABLES
CREATE DATABASE
CREATE TABLE
information_schema.INNODB_SYS_TABLES
information_schema.INNODB_SYS_TABLES
ALTER TABLE
information_schema.INNODB_SYS_TABLES
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
SET SESSION innodb_strict_mode=ON;

SET GLOBAL innodb_default_row_format='dynamic';

CREATE TABLE tab (
   id INT,
   str VARCHAR(50)
) ENGINE=InnoDB;
$ mariadb --user=root
SHOW SESSION VARIABLES
   LIKE 'default_storage_engine';
+------------------------+--------+
| Variable_name          | Value  |
+------------------------+--------+
| default_storage_engine | InnoDB |
+------------------------+--------+
SHOW GLOBAL VARIABLES
   LIKE 'innodb_default_row_format';
+---------------------------+---------+
| Variable_name             | Value   |
+---------------------------+---------+
| innodb_default_row_format | dynamic |
+---------------------------+---------+
CREATE DATABASE hq_sales;
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)
);
SELECT NAME, ROW_FORMAT
FROM information_schema.INNODB_SYS_TABLES
WHERE NAME='hq_sales/invoices';
+-------------------+------------+
| NAME              | ROW_FORMAT |
+-------------------+------------+
| hq_sales/invoices | Dynamic    |
+-------------------+------------+
$ mariadb --user=root
SHOW SESSION VARIABLES
   LIKE 'default_storage_engine';
+------------------------+--------+
| Variable_name          | Value  |
+------------------------+--------+
| default_storage_engine | InnoDB |
+------------------------+--------+
SHOW GLOBAL VARIABLES
   LIKE 'innodb_default_row_format';
+---------------------------+---------+
| Variable_name             | Value   |
+---------------------------+---------+
| innodb_default_row_format | compact |
+---------------------------+---------+
CREATE DATABASE hq_sales;
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 = DYNAMIC;
SELECT NAME, ROW_FORMAT
FROM information_schema.INNODB_SYS_TABLES
WHERE NAME='hq_sales/invoices';
+-------------------+------------+
| NAME              | ROW_FORMAT |
+-------------------+------------+
| hq_sales/invoices | Dynamic    |
+-------------------+------------+
$ mariadb --user=root
SELECT NAME, ROW_FORMAT
FROM information_schema.INNODB_SYS_TABLES
WHERE NAME NOT LIKE 'SYS_%'
AND ROW_FORMAT != 'Dynamic';
+-------------------+------------+
| NAME              | ROW_FORMAT |
+-------------------+------------+
| hq_sales/invoices | Compact    |
+-------------------+------------+
ALTER TABLE hq_sales.invoices
   ROW_FORMAT = DYNAMIC;
SELECT NAME, ROW_FORMAT
FROM information_schema.INNODB_SYS_TABLES
WHERE NAME='hq_sales/invoices';
+-------------------+------------+
| NAME              | ROW_FORMAT |
+-------------------+------------+
| hq_sales/invoices | Dynamic    |
+-------------------+------------+