innodb_flush_log_at_trx_commit
This page is part of MariaDB's Enterprise Documentation.
The parent of this page is: System Variables for MariaDB Enterprise Server
Topics on this page:
Overview
Controls the durability/speed trade-off for commits. Set to 0 (write and flush redo log to disk only once per second), 1 (flush to disk at each commit), 2 (write to log at commit but flush to disk only once per second) or 3 (flush to disk at prepare and at commit, slower and usually redundant). 1 and 3 guarantees that after a crash, committed transactions will not be lost and will be consistent with the binlog and other transactional engines. 2 can get inconsistent and lose transactions if there is a power failure or kernel crash but not if mysqld crashes. 0 has no guarantees in case of crash. 0 and 2 can be faster than 1 or 3.
See also: System Variables for MariaDB Enterprise Server 10.6, in 10.6 CS, in 10.5 ES, in 10.5 CS, in 10.4 ES, in 10.4 CS, in 10.3 ES, in 10.3 CS, in 10.2 ES, and in 10.2 CS
USAGE
The innodb_flush_log_at_trx_commit
system variable can be set in a configuration file:
[mariadb]
innodb_flush_log_at_trx_commit=1
The innodb_flush_log_at_trx_commit
system variable can also be set dynamically at runtime by executing SET GLOBAL:
SET GLOBAL innodb_flush_log_at_trx_commit=1;
When the innodb_flush_log_at_trx_commit
system variable is set dynamically at runtime, its value will be reset the next time the server restarts. To make the value persist on restart, set it in a configuration file too.
DETAILS
The innodb_flush_log_at_trx_commit
system variable configures how often the transactions are flushed to the redo log:
When it is set to 0, nothing is done on commit; rather the log buffer is written and flushed to the InnoDB redo log once a second. This gives better performance, but a server crash can erase the last second of transactions.
When it is set to 1, the log buffer is written to the InnoDB redo log file, and a flush to disk performed after each transaction. This is required for full ACID compliance.
When it is set to 2, the log buffer is written to the InnoDB redo log after each commit, but flushing takes place once a second. Performance is slightly better, but a OS or power outage can cause the last second's transactions to be lost.
When it is set to 3, InnoDB emulates the older implementation of group commit, with 3 syncs to disk per group commit.
PARAMETERS
Command-line | --innodb_flush_log_at_trx_commit[=#] |
Configuration file | Supported |
Dynamic | Yes |
Scope | Global |
Data Type | BIGINT UNSIGNED |
Minimum Value | 0 |
Maximum Value | 3 |
Default Value | 1 |
PRIVILEGES
The innodb_flush_log_at_trx_commit
system variable requires the SUPER
privilege to dynamically set its value at runtime.
EXAMPLES
Full ACID Compliance
For full ACID compliance, set the innodb_flush_log_at_trx_commit
system variable to 1. To also enable the greatest fault tolerance for the instance, enable the Binary Log and set the sync_binlog system variable to 1:
[mariadb]
innodb_flush_log_at_trx_commit=1
log_bin=mariadb-bin
sync_binlog=1
Dynamically Resetting Global Value to Default
The global value of the innodb_flush_log_at_trx_commit
system variable can be dynamically reset to the default value by setting it to DEFAULT
:
SET GLOBAL innodb_flush_log_at_trx_commit=0;
SHOW GLOBAL VARIABLES LIKE 'innodb_flush_log_at_trx_commit';
+--------------------------------+-------+
| Variable_name | Value |
+--------------------------------+-------+
| innodb_flush_log_at_trx_commit | 0 |
+--------------------------------+-------+
SET GLOBAL innodb_flush_log_at_trx_commit=DEFAULT;
SHOW GLOBAL VARIABLES LIKE 'innodb_flush_log_at_trx_commit';
+--------------------------------+-------+
| Variable_name | Value |
+--------------------------------+-------+
| innodb_flush_log_at_trx_commit | 1 |
+--------------------------------+-------+
Invalid Value for Variable
If a user tries to set the innodb_flush_log_at_trx_commit
system variable to an invalid value, then the specific behavior depends on the value of the sql_mode system variable.
If the sql_mode system variable does not contain STRICT_ALL_TABLES
and a user tries to set the innodb_flush_log_at_trx_commit
system variable to an invalid value, then the operation will appear to succeed, but a warning will be raised with the ER_TRUNCATED_WRONG_VALUE error code. The warning will point out that the value was truncated, which means that the value was automatically set to the closest invalid value:
SET GLOBAL innodb_flush_log_at_trx_commit=-1;
SHOW WARNINGS;
+---------+------+----------------------------------------------------------------+
| Level | Code | Message |
+---------+------+----------------------------------------------------------------+
| Warning | 1292 | Truncated incorrect innodb_flush_log_at_trx_commit value: '-1' |
+---------+------+----------------------------------------------------------------+
SHOW GLOBAL VARIABLES LIKE 'innodb_flush_log_at_trx_commit';
+--------------------------------+-------+
| Variable_name | Value |
+--------------------------------+-------+
| innodb_flush_log_at_trx_commit | 0 |
+--------------------------------+-------+
SET GLOBAL innodb_flush_log_at_trx_commit=4;
SHOW WARNINGS;
+---------+------+---------------------------------------------------------------+
| Level | Code | Message |
+---------+------+---------------------------------------------------------------+
| Warning | 1292 | Truncated incorrect innodb_flush_log_at_trx_commit value: '4' |
+---------+------+---------------------------------------------------------------+
SHOW GLOBAL VARIABLES LIKE 'innodb_flush_log_at_trx_commit';
+--------------------------------+-------+
| Variable_name | Value |
+--------------------------------+-------+
| innodb_flush_log_at_trx_commit | 3 |
+--------------------------------+-------+
If the sql_mode system variable does contain STRICT_ALL_TABLES
and a user tries to set the innodb_flush_log_at_trx_commit
system variable to an invalid value, then the operation will fail with the ER_WRONG_VALUE_FOR_VAR error code:
SHOW SESSION VARIABLES LIKE 'sql_mode';
+---------------+-------------------------------------------------------------------------------------------+
| Variable_name | Value |
+---------------+-------------------------------------------------------------------------------------------+
| sql_mode | STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION |
+---------------+-------------------------------------------------------------------------------------------+
SET SESSION sql_mode=CONCAT(@@session.sql_mode, ',STRICT_ALL_TABLES');
SET GLOBAL innodb_flush_log_at_trx_commit=-1;
ERROR 1231 (42000): Variable 'innodb_flush_log_at_trx_commit' can't be set to the value of '-1'
Invalid Type for Variable
If a user tries to set the innodb_flush_log_at_trx_commit
system variable to an invalid argument, then the operation will fail with the ER_WRONG_TYPE_FOR_VAR error code:
SET GLOBAL innodb_flush_log_at_trx_commit='';
ERROR 1232 (42000): Incorrect argument type to variable 'innodb_flush_log_at_trx_commit'
SET GLOBAL innodb_flush_log_at_trx_commit='infinity';
ERROR 1232 (42000): Incorrect argument type to variable 'innodb_flush_log_at_trx_commit'
CHANGE HISTORY
Release Series | History |
---|---|
10.6 Enterprise |
|
10.6 Community |
|
10.5 Enterprise |
|
10.5 Community |
|
10.4 Enterprise |
|
10.4 Community |
|
10.3 Enterprise |
|
10.3 Community |
|
10.2 Enterprise |
|
10.2 Community |
|
EXTERNAL REFERENCES
Information specific to MariaDB SkySQL can be found on the innodb_flush_log_at_trx_commit page in the SkySQL Documentation.