This section describes the InnoDB
-related
command options and system variables.
System variables that are true or false can be enabled at
server startup by naming them, or disabled by using a
--skip-
prefix. For example, to enable or
disable InnoDB
checksums, you can use
--innodb_checksums
or
--skip-innodb_checksums
on the command line, or
innodb_checksums
or
skip-innodb_checksums
in an option file.
System variables that take a numeric value can be specified as
--
on the command line or as
var_name
=value
in option files.
var_name
=value
Many system variables can be changed at runtime (see Section 5.1.5.2, “Dynamic System Variables”).
For information about GLOBAL
and
SESSION
variable scope modifiers, refer to
the
SET
statement documentation.
Certain options control the locations and layout of the
InnoDB
data files.
Section 14.3.7, “InnoDB
Configuration” explains how to use
these options.
Some options, which you might not use initially, help tune
InnoDB
performance characteristics based on
machine capacity and your database
workload. The
performance-related options are explained in
Section 14.3.16, “InnoDB
Performance Tuning” and
Section 14.3.16.2, “InnoDB
Performance and Scalability Enhancements”.
For more information on specifying options and system variables, see Section 4.2.3, “Specifying Program Options”.
Table 14.6. InnoDB
Option/Variable
Reference
InnoDB
Command Options
Deprecated | 5.5.22 | ||
Command-Line Format | --ignore-builtin-innodb | ||
Option-File Format | ignore-builtin-innodb | ||
System Variable Name | ignore_builtin_innodb | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean |
In MySQL 5.1, this option caused the server to behave as if
the built-in InnoDB
were not present, which
enabled InnoDB Plugin
to be used instead.
In MySQL 5.5, InnoDB
is the
default storage engine and InnoDB Plugin
is
not used, so this option has no effect. As of MySQL 5.5.22, it
is deprecated and its use results in a warning.
Controls loading of the InnoDB
storage
engine, if the server was compiled with
InnoDB
support. This option has a tristate
format, with possible values of OFF
,
ON
, or FORCE
. See
Section 5.1.8.1, “Installing and Uninstalling Plugins”.
To disable InnoDB
, use
--innodb=OFF
or
--skip-innodb
.
In this case, because the default storage engine is
InnoDB
, the server will not start
unless you also use
--default-storage-engine
to set
the default to some other engine.
Command-Line Format | --innodb-status-file | ||
Option-File Format | innodb-status-file | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Controls whether InnoDB
creates a file
named
innodb_status.
in the MySQL data directory. If enabled,
<pid>
InnoDB
periodically writes the output of
SHOW ENGINE
INNODB STATUS
to this file.
By default, the file is not created. To create it, start
mysqld with the
--innodb-status-file=1
option.
The file is deleted during normal shutdown.
Disable the InnoDB
storage engine. See the
description of --innodb
.
InnoDB
System Variables
Deprecated | 5.5.22 | ||
Command-Line Format | --ignore-builtin-innodb | ||
Option-File Format | ignore-builtin-innodb | ||
System Variable Name | ignore_builtin_innodb | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean |
See the description of
--ignore-builtin-innodb
under
“InnoDB
Command Options”
earlier in this section.
Command-Line Format | --innodb_adaptive_flushing=# | ||
Option-File Format | innodb_adaptive_flushing | ||
System Variable Name | innodb_adaptive_flushing | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
Specifies whether to use the adaptive flushing algorithm to
dynamically adjust the rate of
dirty page flushing in
the InnoDB
buffer pool based on
the workload. Dynamically adjusting the flush rate is intended
to avoid bursts of I/O activity. This setting is enabled by
default. See
Section 14.3.16.2.12, “Controlling the Flushing Rate of Dirty Pages from the InnoDB Buffer Pool” for
more information. For general I/O tuning advice, see
Section 8.5.7, “Optimizing InnoDB
Disk I/O”.
Command-Line Format | --innodb_adaptive_hash_index=# | ||
Option-File Format | innodb_adaptive_hash_index | ||
System Variable Name | innodb_adaptive_hash_index | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
Whether the InnoDB
adaptive hash
index is enabled or disabled. The adaptive hash index
feature is useful for some workloads, and not for others;
conduct benchmarks with it both enabled and disabled, using
realistic workloads. See
Section 14.3.5.13.5, “Adaptive Hash Indexes” for details. This
variable is enabled by default. Use
--skip-innodb_adaptive_hash_index
at server
startup to disable it.
innodb_additional_mem_pool_size
Command-Line Format | --innodb_additional_mem_pool_size=# | ||
Option-File Format | innodb_additional_mem_pool_size | ||
System Variable Name | innodb_additional_mem_pool_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 8388608 | ||
Range | 2097152 .. 4294967295 |
The size in bytes of a memory pool InnoDB
uses to store data
dictionary information and other internal data
structures. The more tables you have in your application, the
more memory you need to allocate here. If
InnoDB
runs out of memory in this pool, it
starts to allocate memory from the operating system and writes
warning messages to the MySQL error log. The default value is
8MB.
This variable relates to the InnoDB
internal memory allocator, which is unused if
innodb_use_sys_malloc
is
enabled.
Command-Line Format | --innodb_autoextend_increment=# | ||
Option-File Format | innodb_autoextend_increment | ||
System Variable Name | innodb_autoextend_increment | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 64 | ||
Range | 1 .. 1000 |
The increment size (in MB) for extending the size of an
auto-extending shared tablespace file when it becomes full.
The default value is 8. This variable does not affect the
per-table tablespace files that are created if you use
innodb_file_per_table=1
.
Those files are auto-extending regardless of the value of
innodb_autoextend_increment
.
The initial extensions are by small amounts, after which
extensions occur in increments of 4MB.
Command-Line Format | --innodb_autoinc_lock_mode=# | ||
Option-File Format | innodb_autoinc_lock_mode | ||
System Variable Name | innodb_autoinc_lock_mode | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 1 | ||
Valid Values | 0 | ||
1 | |||
2 |
The locking mode to use for generating auto-increment values.
The permissible values are 0, 1, or 2, for
“traditional”, “consecutive”, or
“interleaved” lock mode, respectively.
Section 14.3.10.5, “AUTO_INCREMENT
Handling in InnoDB
”, describes
the characteristics of these modes.
This variable has a default of 1 (“consecutive” lock mode).
Introduced | 5.5.4 | ||
Command-Line Format | --innodb_buffer_pool_instances=# | ||
Option-File Format | innodb_buffer_pool_instances | ||
System Variable Name | innodb_buffer_pool_instances | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 1 | ||
Range | 1 .. 64 |
The number of regions that the
InnoDB
buffer pool is divided
into. For systems with buffer pools in the multi-gigabyte
range, dividing the buffer pool into separate instances can
improve concurrency, by reducing contention as different
threads read and write to cached pages. Each page that is
stored in or read from the buffer pool is assigned to one of
the buffer pool instances randomly, using a hashing function.
Each buffer pool manages its own free lists, flush lists,
LRUs, and all other data structures connected to a buffer
pool, and is protected by its own buffer pool mutex.
This option takes effect only when you set the
innodb_buffer_pool_size
to a size of 1
gigabyte or more. The total size you specify is divided among
all the buffer pools. For best efficiency, specify a
combination of
innodb_buffer_pool_instances
and innodb_buffer_pool_size
so that each buffer pool instance is at least 1 gigabyte.
Command-Line Format | --innodb_buffer_pool_size=# | ||
Option-File Format | innodb_buffer_pool_size | ||
System Variable Name | innodb_buffer_pool_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 134217728 | ||
Min Value | 5242880 |
The size in bytes of the memory buffer
InnoDB
uses to cache data and indexes of
its tables. The default value is 128MB. The maximum value
depends on the CPU architecture; the maximum is 4294967295
(232-1) on 32-bit systems and
18446744073709551615 (264-1) on
64-bit systems. On 32-bit systems, the CPU architecture and
operating system may impose a lower practical maximum size
than the stated maximum. When the size of the buffer pool is
greater than 1GB, setting
innodb_buffer_pool_instances
to a value greater than 1 can improve the scalability on a
busy server.
The larger you set this value, the less disk I/O is needed to access data in tables. On a dedicated database server, you may set this to up to 80% of the machine physical memory size. Be prepared to scale back this value if these other issues occur:
Competition for physical memory might cause paging in the operating system.
InnoDB reserves additional memory for buffers and control structures, so that the total allocated space is approximately 10% greater than the specified size.
The address space must be contiguous, which can be an issue on Windows systems with DLLs that load at specific addresses.
The time to initialize the buffer pool is roughly
proportional to its size. On large installations, this
initialization time may be significant. For example, on a
modern Linux x86_64 server, initialization of a 10GB
buffer pool takes approximately 6 seconds. See
Section 8.9.1, “The InnoDB
Buffer Pool”.
Command-Line Format | --innodb_change_buffering=# | ||
Option-File Format | innodb_change_buffering | ||
System Variable Name | innodb_change_buffering | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.5.3) | |||
Type | enumeration | ||
Default | inserts | ||
Valid Values | inserts | ||
none | |||
Permitted Values (>= 5.5.4) | |||
Type | enumeration | ||
Default | all | ||
Valid Values | inserts | ||
deletes | |||
purges | |||
changes | |||
all | |||
none |
Whether InnoDB
performs change
buffering, an optimization that delays write operations to
secondary indexes so that the I/O operations can be performed
sequentially. The permitted values are
inserts
(buffer insert operations),
deletes
(buffer delete operations; strictly
speaking, the writes that mark index records for later
deletion during a purge operation), changes
(buffer insert and delete-marking operations),
purges
(buffer purge operations, the writes
when deleted index entries are finally garbage-collected),
all
(buffer insert, delete-marking, and
purge operations) and none
(do not buffer
any operations). The default is all
. For
details, see
Section 14.3.16.2.4, “Controlling InnoDB Change Buffering”.
Command-Line Format | --innodb_checksums | ||
Option-File Format | innodb_checksums | ||
System Variable Name | innodb_checksums | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
InnoDB
can use checksum validation on all
pages read from the disk to ensure extra fault tolerance
against broken hardware or data files. This validation is
enabled by default. However, under some rare circumstances
(such as when running benchmarks) this extra safety feature is
unneeded and can be disabled with
--skip-innodb-checksums
.
Command-Line Format | --innodb_commit_concurrency=# | ||
Option-File Format | innodb_commit_concurrency | ||
System Variable Name | innodb_commit_concurrency | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 1000 |
The number of threads that can commit at the same time. A value of 0 (the default) permits any number of transactions to commit simultaneously.
The value of
innodb_commit_concurrency
cannot be changed at runtime from zero to nonzero or vice
versa. The value can be changed from one nonzero value to
another.
Command-Line Format | --innodb_concurrency_tickets=# | ||
Option-File Format | innodb_concurrency_tickets | ||
System Variable Name | innodb_concurrency_tickets | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 500 | ||
Range | 1 .. 4294967295 |
The number of threads that can enter InnoDB
concurrently is determined by the
innodb_thread_concurrency
variable. A thread is placed in a queue when it tries to enter
InnoDB
if the number of threads has already
reached the concurrency limit. When a thread is permitted to
enter InnoDB
, it is given a number of
“free tickets” equal to the value of
innodb_concurrency_tickets
,
and the thread can enter and leave InnoDB
freely until it has used up its tickets. After that point, the
thread again becomes subject to the concurrency check (and
possible queuing) the next time it tries to enter
InnoDB
. The default value is 500.
Command-Line Format | --innodb_data_file_path=name | ||
Option-File Format | innodb_data_file_path | ||
System Variable Name | innodb_data_file_path | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string | ||
Default | ibdata1:10M:autoextend |
The paths to individual data files and their sizes. The full
directory path to each data file is formed by concatenating
innodb_data_home_dir
to each
path specified here. The file sizes are specified in KB, MB,
or GB (1024MB) by appending K
,
M
, or G
to the size
value. The sum of the sizes of the files must be at least
slightly larger than 10MB. If you do not specify
innodb_data_file_path
, the
default behavior is to create a single auto-extending data
file, slightly larger than 10MB, named
ibdata1
. The size limit of individual
files is determined by your operating system. You can set the
file size to more than 4GB on those operating systems that
support big files. You can also use raw disk partitions as
data files. For detailed information on configuring
InnoDB
tablespace files, see
Section 14.3.7, “InnoDB
Configuration”.
Command-Line Format | --innodb_data_home_dir=path | ||
Option-File Format | innodb_data_home_dir | ||
System Variable Name | innodb_data_home_dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The common part of the directory path for all
InnoDB
data files in the shared tablespace.
This setting does not affect the location of per-file
tablespaces when
innodb_file_per_table
is
enabled. The default value is the MySQL data directory. If you
specify the value as an empty string, you can use absolute
file paths in
innodb_data_file_path
.
Command-Line Format | --innodb-doublewrite | ||
Option-File Format | innodb_doublewrite | ||
System Variable Name | innodb_doublewrite | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean |
If this variable is enabled (the default),
InnoDB
stores all data twice, first to the
doublewrite buffer, and then to the actual data files. This
variable can be turned off with
--skip-innodb_doublewrite
for benchmarks or cases when top performance is needed rather
than concern for data integrity or possible failures.
Command-Line Format | --innodb_fast_shutdown[=#] | ||
Option-File Format | innodb_fast_shutdown | ||
System Variable Name | innodb_fast_shutdown | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 1 | ||
Valid Values | 0 | ||
1 | |||
2 |
The InnoDB
shutdown mode. If the value is
0, InnoDB
does a
slow shutdown, a
full purge and an insert
buffer merge before shutting down. If the value is 1 (the
default), InnoDB
skips these operations at
shutdown, a process known as a
fast shutdown. If
the value is 2, InnoDB
flushes its logs and
shuts down cold, as if MySQL had crashed; no committed
transactions are lost, but the
crash recovery
operation makes the next startup take longer.
The slow shutdown can take minutes, or even hours in extreme cases where substantial amounts of data are still buffered. Use the slow shutdown technique before upgrading or downgrading between MySQL major releases, so that all data files are fully prepared in case the upgrade process updates the file format.
Use innodb_fast_shutdown=2
in emergency or
troubleshooting situations, to get the absolute fastest
shutdown if data is at risk of corruption.
Command-Line Format | --innodb_file_format=# | ||
Option-File Format | innodb_file_format | ||
System Variable Name | innodb_file_format | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.5.6) | |||
Type | string | ||
Default | Barracuda | ||
Valid Values | Antelope | ||
Barracuda | |||
Permitted Values (>= 5.5.7) | |||
Type | string | ||
Default | Antelope | ||
Valid Values | Antelope | ||
Barracuda |
The file format to use for new
InnoDB
tables. Currently,
Antelope
and Barracuda
are supported. This applies only for tables that have their
own tablespace, so for it to have an effect,
innodb_file_per_table
must be
enabled. The Barracuda
file format is required for certain InnoDB features such as
table compression.
Command-Line Format | --innodb_file_format_check=# | ||
Option-File Format | innodb_file_format_check | ||
System Variable Name | innodb_file_format_check | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string | ||
Default | Antelope | ||
Permitted Values (>= 5.5.1) | |||
Type | string | ||
Default | Barracuda | ||
Permitted Values (>= 5.5.5) | |||
Type | boolean | ||
Default | ON |
As of MySQL 5.5.5, this variable can be set to 1 or 0 at
server startup to enable or disable whether
InnoDB
checks the file format tag in the
shared tablespace (for example, Antelope
or
Barracuda
). If the tag is checked and is
higher than that supported by the current version of
InnoDB
, an error occurs and
InnoDB
does not start. If the tag is not
higher, InnoDB
sets the value of
innodb_file_format_max
to the
file format tag.
Before MySQL 5.5.5, this variable can be set to 1 or 0 at
server startup to enable or disable whether
InnoDB
checks the file format tag in the
shared tablespace. If the tag is checked and is higher than
that supported by the current version of
InnoDB
, an error occurs and
InnoDB
does not start. If the tag is not
higher, InnoDB
sets the value of
innodb_file_format_check
to
the file format tag, which is the value seen at runtime.
Despite the default value sometimes being displayed as
ON
or OFF
, always use
the numeric values 1 or 0 to turn this option on or off in
your configuration file or command line.
Introduced | 5.5.5 | ||
Command-Line Format | --innodb_file_format_max=# | ||
Option-File Format | innodb_file_format_max | ||
System Variable Name | innodb_file_format_max | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string | ||
Default | Antelope | ||
Valid Values | Antelope | ||
Barracuda |
At server startup, InnoDB
sets the value of
innodb_file_format_max
to the
file format tag in the shared tablespace (for example,
Antelope
or Barracuda
).
If the server creates or opens a table with a
“higher” file format, it sets the value of
innodb_file_format_max
to
that format.
This variable was added in MySQL 5.5.5.
Command-Line Format | --innodb_file_per_table | ||
Option-File Format | innodb_file_per_table | ||
System Variable Name | innodb_file_per_table | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.5.6) | |||
Type | boolean | ||
Default | ON | ||
Permitted Values (>= 5.5.7) | |||
Type | boolean | ||
Default | OFF |
If innodb_file_per_table
is
disabled (the default), InnoDB
creates
tables in the system
tablespace. If
innodb_file_per_table
is
enabled, InnoDB
creates each new table
using its own
.ibd
file for storing data and indexes, rather than in the
system tablespace. See
Section 14.3.9.2, “Using Per-Table Tablespaces” for information
about advantages, disadvantages, and features, such as
InnoDB
table compression, that only work
for tables stored in separate tablespaces.
innodb_flush_log_at_trx_commit
Command-Line Format | --innodb_flush_log_at_trx_commit[=#] | ||
Option-File Format | innodb_flush_log_at_trx_commit | ||
System Variable Name | innodb_flush_log_at_trx_commit | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | 1 | ||
Valid Values | 0 | ||
1 | |||
2 |
If the value of
innodb_flush_log_at_trx_commit
is 0, the log buffer is written out to the log file once per
second and the flush to disk operation is performed on the log
file, but nothing is done at a transaction commit. When the
value is 1 (the default), the log buffer is written out to the
log file at each transaction commit and the flush to disk
operation is performed on the log file. When the value is 2,
the log buffer is written out to the file at each commit, but
the flush to disk operation is not performed on it. However,
the flushing on the log file takes place once per second also
when the value is 2. Note that the once-per-second flushing is
not 100% guaranteed to happen every second, due to process
scheduling issues.
The default value of 1 is required for full ACID compliance.
You can achieve better performance by setting the value
different from 1, but then you can lose up to one second worth
of transactions in a crash. With a value of 0, any
mysqld process crash can erase the last
second of transactions. With a value of 2, only an operating
system crash or a power outage can erase the last second of
transactions. InnoDB
's
crash recovery
works regardless of the value.
For the greatest possible durability and consistency in a
replication setup using InnoDB
with
transactions, use
innodb_flush_log_at_trx_commit=1
and
sync_binlog=1
in your master server
my.cnf
file.
Many operating systems and some disk hardware fool the
flush-to-disk operation. They may tell
mysqld that the flush has taken place,
even though it has not. Then the durability of transactions
is not guaranteed even with the setting 1, and in the worst
case a power outage can even corrupt the
InnoDB
database. Using a battery-backed
disk cache in the SCSI disk controller or in the disk itself
speeds up file flushes, and makes the operation safer. You
can also try using the Unix command
hdparm to disable the caching of disk
writes in hardware caches, or use some other command
specific to the hardware vendor.
Command-Line Format | --innodb_flush_method=name | ||
Option-File Format | innodb_flush_method | ||
System Variable Name | innodb_flush_method | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type (linux) | enumeration | ||
Default | fdatasync | ||
Valid Values | fdatasync | ||
O_DSYNC | |||
O_DIRECT | |||
Permitted Values | |||
Type (hpux) | enumeration | ||
Default | fdatasync | ||
Valid Values | fdatasync | ||
O_DSYNC | |||
O_DIRECT | |||
Permitted Values | |||
Type (solaris) | enumeration | ||
Default | fdatasync | ||
Valid Values | fdatasync | ||
O_DSYNC | |||
O_DIRECT |
By default, InnoDB
uses the
fsync()
system call to flush both the data
and log files. If
innodb_flush_method
option is
set to O_DSYNC
, InnoDB
uses O_SYNC
to open and flush the log
files, and fsync()
to flush the data files.
If O_DIRECT
is specified (available on some
GNU/Linux versions, FreeBSD, and Solaris),
InnoDB
uses O_DIRECT
(or
directio()
on Solaris) to open the data
files, and uses fsync()
to flush both the
data and log files. Note that InnoDB
uses
fsync()
instead of
fdatasync()
, and it does not use
O_DSYNC
by default because there have been
problems with it on many varieties of Unix. This variable is
relevant only for Unix. On Windows, the flush method is always
async_unbuffered
and cannot be changed.
Depending on hardware configuration, setting
innodb_flush_method
to
O_DIRECT
can either have either a positive
or negative effect on performance. Benchmark your particular
configuration to decide which setting to use. The mix of read
and write operations in your workload can also affect which
setting performs better for you. For example, on a system with
a hardware RAID controller and battery-backed write cache,
O_DIRECT
can help to avoid double buffering
between the InnoDB
buffer pool and the
operating system's filesystem cache. On some systems where
InnoDB
data and log files are located on a
SAN, the default value or O_DSYNC
might be
faster for a read-heavy workload with mostly
SELECT
statements. Always test this
parameter with the same type of hardware and workload that
reflects your production environment.
Formerly, a value of fdatasync
also
specified the default behavior. This value was removed, due to
confusion that a value of fdatasync
caused
fsync()
system calls rather than
fdatasync()
for flushing. To obtain the
default value now, do not set any value for
innodb_flush_method
at
startup.
Introduced | 5.5.18 | ||
Command-Line Format | --innodb_force_load_corrupted | ||
Option-File Format | innodb_force_load_corrupted | ||
System Variable Name | innodb_force_load_corrupted | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Lets InnoDB load tables at startup that are marked as corrupted. Use only during troubleshooting, to recover data that is otherwise inaccessible. When troubleshooting is complete, turn this setting back off and restart the server.
Command-Line Format | --innodb_force_recovery=# | ||
Option-File Format | innodb_force_recovery | ||
System Variable Name | innodb_force_recovery | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | enumeration | ||
Default | 0 | ||
Valid Values | 0 | ||
1 | |||
2 | |||
3 | |||
4 | |||
5 | |||
6 |
The crash recovery mode. Possible values are from 0 to 6. The
meanings of these values are described in
Section 14.3.20.2, “Forcing InnoDB
Recovery”.
Only set this variable greater than 0 in an emergency
situation, to dump your tables from a corrupt database. As a
safety measure, InnoDB
prevents any
changes to its data when this variable is greater than 0.
This restriction also prohibits some queries that use
WHERE
or ORDER BY
clauses, because high values can prevent queries from using
indexes.
Command-Line Format | --innodb_io_capacity=# | ||
Option-File Format | innodb_io_capacity | ||
System Variable Name | innodb_io_capacity | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 200 | ||
Range | 100 .. 2**32-1 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 200 | ||
Range | 100 .. 2**64-1 |
An upper limit on the I/O activity performed by the
InnoDB
background tasks, such as flushing
pages from the buffer
pool and merging data from the
insert buffer. The
default value is 200. For busy systems capable of higher I/O
rates, you can set a higher value at server startup, to help
the server handle the background maintenance work associated
with a high rate of row changes. For systems with individual
5400 RPM or 7200 RPM drives, you might lower the value to the
former default of 100
.
The innodb_io_capacity
limit
is a total limit for all buffer pool instances. When dirty
pages are flushed, the
innodb_io_capacity
limit is
divided equally among buffer pool instances.
This parameter should be set to approximately the number of I/O operations that the system can perform per second. Ideally, keep this setting as low as practical, but not so low that these background activities fall behind. If the value is too high, data is removed from the buffer pool and insert buffer too quickly to provide significant benefit from the caching.
The value represents an estimated proportion of the I/O operations per second (IOPS) available to older-generation disk drives that could perform about 100 IOPS. The current default of 200 reflects that modern storage devices are capable of much higher I/O rates.
In general, you can increase the value as a function of the
number of drives used for InnoDB
I/O, particularly fast drives capable of high numbers of IOPS.
For example, systems that use multiple disks or solid-state
disks for InnoDB
are likely to
benefit from the ability to control this parameter.
Although you can specify a very high number, in practice such large values have little if any benefit; for example, a value of one million would be considered very high.
You can set the innodb_io_capacity
value to
any number 100 or greater, and the default value is
200
. You can set the value of this
parameter in the MySQL option file (my.cnf
or my.ini
) or change it dynamically with
the SET GLOBAL
command, which requires the
SUPER
privilege.
See Section 14.3.16.2.11, “Controlling the InnoDB Master Thread I/O Rate” for
more guidelines about this option. For general information
about InnoDB I/O performance, see
Section 8.5.7, “Optimizing InnoDB
Disk I/O”.
Introduced | 5.5.14 | ||
Command-Line Format | --innodb_large_prefix | ||
Option-File Format | innodb_large_prefix | ||
System Variable Name | innodb_large_prefix | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Enable this option to allow index key prefixes longer than 767
bytes (up to 3072 bytes), for InnoDB
tables
that use the
DYNAMIC
and
COMPRESSED
row formats. (Creating such tables also requires the option
values
innodb_file_format=barracuda
and
innodb_file_per_table=true
.)
See Section 14.3.10.7, “Limits on InnoDB
Tables” for the relevant
maximums associated with index key prefixes under various
settings.
For tables using the
REDUNDANT
and
COMPACT
row formats, this option does not affect the allowed key
prefix length. It does introduce a new error possibility. When
this setting is enabled, attempting to create an index prefix
with a key length greater than 3072 for a
REDUNDANT
or COMPACT
table causes an error
ER_INDEX_COLUMN_TOO_LONG
(1727).
Command-Line Format | --innodb_lock_wait_timeout=# | ||
Option-File Format | innodb_lock_wait_timeout | ||
System Variable Name | innodb_lock_wait_timeout | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 50 | ||
Range | 1 .. 1073741824 |
The timeout in seconds an InnoDB
transaction waits for a row lock before giving up. The default
value is 50 seconds. A transaction that tries to access a row
that is locked by another InnoDB
transaction waits at most this many seconds for write access
to the row before issuing the following error:
ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction
When a lock wait timeout occurs, the current statement is
rolled back (not the entire transaction). To have the entire
transaction roll back, start the server with the
--innodb_rollback_on_timeout
option. See also Section 14.3.20.4, “InnoDB
Error Handling”.
You might decrease this value for highly interactive applications or OLTP systems, to display user feedback quickly or put the update into a queue for processing later. You might increase this value for long-running back-end operations, such as a transform step in a data warehouse that waits for other large insert or update operations to finish.
innodb_lock_wait_timeout
applies to InnoDB
row locks only. A MySQL
table lock does not happen inside InnoDB
and this timeout does not apply to waits for table locks.
The lock wait timeout value does not apply to deadlocks,
because InnoDB
detects them immediately and
rolls back one of the deadlocked transactions.
innodb_locks_unsafe_for_binlog
Command-Line Format | --innodb_locks_unsafe_for_binlog | ||
Option-File Format | innodb_locks_unsafe_for_binlog | ||
System Variable Name | innodb_locks_unsafe_for_binlog | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
This variable affects how InnoDB
uses gap
locking for searches and index scans. Normally,
InnoDB
uses an algorithm called
next-key locking that combines
index-row locking with gap locking. InnoDB
performs row-level locking in such a way that when it searches
or scans a table index, it sets shared or exclusive locks on
the index records it encounters. Thus, the row-level locks are
actually index-record locks. In addition, a next-key lock on
an index record also affects the “gap” before
that index record. That is, a next-key lock is an index-record
lock plus a gap lock on the gap preceding the index record. If
one session has a shared or exclusive lock on record
R
in an index, another session cannot
insert a new index record in the gap immediately before
R
in the index order. See
Section 14.3.5.6, “InnoDB
Record, Gap, and Next-Key Locks”.
By default, the value of
innodb_locks_unsafe_for_binlog
is 0 (disabled), which means that gap locking is enabled:
InnoDB
uses next-key locks for searches and
index scans. To enable the variable, set it to 1. This causes
gap locking to be disabled: InnoDB
uses
only index-record locks for searches and index scans.
Enabling
innodb_locks_unsafe_for_binlog
does not disable the use of gap locking for foreign-key
constraint checking or duplicate-key checking.
The effect of enabling
innodb_locks_unsafe_for_binlog
is similar to but not identical to setting the transaction
isolation level to READ
COMMITTED
:
Enabling
innodb_locks_unsafe_for_binlog
is a global setting and affects all sessions, whereas the
isolation level can be set globally for all sessions, or
individually per session.
innodb_locks_unsafe_for_binlog
can be set only at server startup, whereas the isolation
level can be set at startup or changed at runtime.
READ COMMITTED
therefore
offers finer and more flexible control than
innodb_locks_unsafe_for_binlog
.
For additional details about the effect of isolation level on
gap locking, see Section 13.3.6, “SET TRANSACTION
Syntax”.
Enabling
innodb_locks_unsafe_for_binlog
may cause phantom problems because other sessions can insert
new rows into the gaps when gap locking is disabled. Suppose
that there is an index on the id
column of
the child
table and that you want to read
and lock all rows from the table having an identifier value
larger than 100, with the intention of updating some column in
the selected rows later:
SELECT * FROM child WHERE id > 100 FOR UPDATE;
The query scans the index starting from the first record where
id
is greater than 100. If the locks set on
the index records in that range do not lock out inserts made
in the gaps, another session can insert a new row into the
table. Consequently, if you were to execute the same
SELECT
again within the same
transaction, you would see a new row in the result set
returned by the query. This also means that if new items are
added to the database, InnoDB
does not
guarantee serializability. Therefore, if
innodb_locks_unsafe_for_binlog
is enabled, InnoDB
guarantees at most an
isolation level of READ
COMMITTED
. (Conflict serializability is still
guaranteed.) For additional information about phantoms, see
Section 14.3.5.7, “Avoiding the Phantom Problem Using Next-Key Locking”.
Enabling
innodb_locks_unsafe_for_binlog
has additional effects:
For UPDATE
or
DELETE
statements,
InnoDB
holds locks only for rows that
it updates or deletes. Record locks for nonmatching rows
are released after MySQL has evaluated the
WHERE
condition. This greatly reduces
the probability of deadlocks, but they can still happen.
For UPDATE
statements, if a
row is already locked, InnoDB
performs
a “semi-consistent” read, returning the
latest committed version to MySQL so that MySQL can
determine whether the row matches the
WHERE
condition of the
UPDATE
. If the row matches
(must be updated), MySQL reads the row again and this time
InnoDB
either locks it or waits for a
lock on it.
Consider the following example, beginning with this table:
CREATE TABLE t (a INT NOT NULL, b INT) ENGINE = InnoDB; INSERT INTO t VALUES (1,2),(2,3),(3,2),(4,3),(5,2); COMMIT;
In this case, table has no indexes, so searches and index scans use the hidden clustered index for record locking (see Section 14.3.5.13.2, “Clustered and Secondary Indexes”).
Suppose that one client performs an
UPDATE
using these statements:
SET autocommit = 0; UPDATE t SET b = 5 WHERE b = 3;
Suppose also that a second client performs an
UPDATE
by executing these
statements following those of the first client:
SET autocommit = 0; UPDATE t SET b = 4 WHERE b = 2;
As InnoDB
executes each
UPDATE
, it first acquires an
exclusive lock for each row, and then determines whether to
modify it. If InnoDB
does not
modify the row and
innodb_locks_unsafe_for_binlog
is enabled, it releases the lock. Otherwise,
InnoDB
retains the lock until the
end of the transaction. This affects transaction processing as
follows.
If
innodb_locks_unsafe_for_binlog
is disabled, the first UPDATE
acquires x-locks and does not release any of them:
x-lock(1,2); retain x-lock x-lock(2,3); update(2,3) to (2,5); retain x-lock x-lock(3,2); retain x-lock x-lock(4,3); update(4,3) to (4,5); retain x-lock x-lock(5,2); retain x-lock
The second UPDATE
blocks as
soon as it tries to acquire any locks (because first update
has retained locks on all rows), and does not proceed until
the first UPDATE
commits or
rolls back:
x-lock(1,2); block and wait for first UPDATE to commit or roll back
If
innodb_locks_unsafe_for_binlog
is enabled, the first UPDATE
acquires x-locks and releases those for rows that it does not
modify:
x-lock(1,2); unlock(1,2) x-lock(2,3); update(2,3) to (2,5); retain x-lock x-lock(3,2); unlock(3,2) x-lock(4,3); update(4,3) to (4,5); retain x-lock x-lock(5,2); unlock(5,2)
For the second UPDATE
,
InnoDB
does a
“semi-consistent” read, returning the latest
committed version of each row to MySQL so that MySQL can
determine whether the row matches the WHERE
condition of the UPDATE
:
x-lock(1,2); update(1,2) to (1,4); retain x-lock x-lock(2,3); unlock(2,3) x-lock(3,2); update(3,2) to (3,4); retain x-lock x-lock(4,3); unlock(4,3) x-lock(5,2); update(5,2) to (5,4); retain x-lock
Command-Line Format | --innodb_log_buffer_size=# | ||
Option-File Format | innodb_log_buffer_size | ||
System Variable Name | innodb_log_buffer_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 8388608 | ||
Range | 262144 .. 4294967295 |
The size in bytes of the buffer that InnoDB
uses to write to the log files on disk. The default value is
8MB. A large log buffer enables large transactions to run
without a need to write the log to disk before the
transactions commit. Thus, if you have big transactions,
making the log buffer larger saves disk I/O.
Command-Line Format | --innodb_log_file_size=# | ||
Option-File Format | innodb_log_file_size | ||
System Variable Name | innodb_log_file_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 5242880 | ||
Range | 1048576 .. 4294967295 |
The size in bytes of each log file in a log group. The
combined size of log files cannot exceed 3.99999999068677 GB
which is equal to the 4294967295 range limit. A pair of 2047
MB log files, for example, would allow you to approach the
range limit but not exceed it. The default value is 5MB.
Sensible values range from 1MB to
1/N
-th of the size of the buffer
pool, where N
is the number of log
files in the group. The larger the value, the less checkpoint
flush activity is needed in the buffer pool, saving disk I/O.
But larger log files also mean that recovery is slower in case
of a crash.
Command-Line Format | --innodb_log_files_in_group=# | ||
Option-File Format | innodb_log_files_in_group | ||
System Variable Name | innodb_log_files_in_group | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 2 | ||
Range | 2 .. 100 |
The number of log files in the log group.
InnoDB
writes to the files in a circular
fashion. The default (and recommended) value is 2.
Command-Line Format | --innodb_log_group_home_dir=path | ||
Option-File Format | innodb_log_group_home_dir | ||
System Variable Name | innodb_log_group_home_dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The directory path to the InnoDB
redo log files. If you do
not specify any InnoDB
log variables, the
default is to create two files named
ib_logfile0
and
ib_logfile1
in the MySQL data directory.
Their size is given by the size of the
innodb_log_file_size
system
variable.
Command-Line Format | --innodb_max_dirty_pages_pct=# | ||
Option-File Format | innodb_max_dirty_pages_pct | ||
System Variable Name | innodb_max_dirty_pages_pct | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 75 | ||
Range | 0 .. 99 |
This is an integer in the range from 0 to 99. The default
value is 75. The main thread in InnoDB
tries to write pages from the buffer pool so that the
percentage of dirty (not yet written) pages will not exceed
this value.
Command-Line Format | --innodb_max_purge_lag=# | ||
Option-File Format | innodb_max_purge_lag | ||
System Variable Name | innodb_max_purge_lag | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 |
This variable controls how to delay
INSERT
,
UPDATE
, and
DELETE
operations when purge
operations are lagging (see
Section 14.3.5.12, “InnoDB
Multi-Versioning”). The default value
0 (no delays).
The InnoDB
transaction system maintains a
list of transactions that have index records delete-marked by
UPDATE
or
DELETE
operations. Let the
length of this list be purge_lag
.
When purge_lag
exceeds
innodb_max_purge_lag
, each
INSERT
,
UPDATE
, and
DELETE
operation is delayed by
((purge_lag
/innodb_max_purge_lag
)×10)–5
milliseconds. The delay is computed in the beginning of a
purge batch, every ten seconds. The operations are not delayed
if purge cannot run because of an old
consistent read
view that could see the rows to be purged.
A typical setting for a problematic workload might be 1
million, assuming that transactions are small, only 100 bytes
in size, and it is permissible to have 100MB of unpurged
InnoDB
table rows.
The lag value is displayed as the history list length in the
TRANSACTIONS
section of InnoDB Monitor
output. For example, if the output includes the following
lines, the lag value is 20:
------------ TRANSACTIONS ------------ Trx id counter 0 290328385 Purge done for trx's n:o < 0 290315608 undo n:o < 0 17 History list length 20
Has no effect.
Command-Line Format | --innodb_old_blocks_pct=# | ||
Option-File Format | innodb_old_blocks_pct | ||
System Variable Name | innodb_old_blocks_pct | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 37 | ||
Range | 5 .. 95 |
Specifies the approximate percentage of the
InnoDB
buffer pool used for
the old block sublist. The
range of values is 5 to 95. The default value is 37 (that is,
3/8 of the pool). See
Section 14.3.16.2.15, “Making the Buffer Pool Scan Resistant” for
more information. See Section 8.9.1, “The InnoDB
Buffer Pool” for
information about buffer pool management, such as the
LRU algorithm and
eviction policies.
Command-Line Format | --innodb_old_blocks_time=# | ||
Option-File Format | innodb_old_blocks_time | ||
System Variable Name | innodb_old_blocks_time | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 2**32-1 |
Non-zero values protect against the buffer pool being filled up by data that is referenced only for a brief period, such as during a full table scan. Increasing this value offers more protection against full table scans interfering with data cached in the buffer pool.
Specifies how long in milliseconds (ms) a block inserted into the old sublist must stay there after its first access before it can be moved to the new sublist. If the value is 0, a block inserted into the old sublist moves immediately to the new sublist the first time it is accessed, no matter how soon after insertion the access occurs. If the value is greater than 0, blocks remain in the old sublist until an access occurs at least that many ms after the first access. For example, a value of 1000 causes blocks to stay in the old sublist for 1 second after the first access before they become eligible to move to the new sublist.
This variable is often used in combination with
innodb_old_blocks_pct
. See
Section 14.3.16.2.15, “Making the Buffer Pool Scan Resistant” for
more information. See Section 8.9.1, “The InnoDB
Buffer Pool” for
information about buffer pool management, such as the
LRU algorithm and
eviction policies.
Command-Line Format | --innodb_open_files=# | ||
Option-File Format | innodb_open_files | ||
System Variable Name | innodb_open_files | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 300 | ||
Range | 10 .. 4294967295 |
This variable is relevant only if you use multiple
InnoDB
tablespaces. It
specifies the maximum number of
.ibd
files that MySQL can keep open at one time. The minimum
value is 10. The default value is 300.
The file descriptors used for .ibd
files
are for InnoDB
tables only. They are
independent of those specified by the
--open-files-limit
server
option, and do not affect the operation of the table cache.
Introduced | 5.5.30 | ||
Command-Line Format | --innodb_print_all_deadlocks=# | ||
Option-File Format | innodb_print_all_deadlocks | ||
System Variable Name | innodb_print_all_deadlocks | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
When this option is enabled, information about all
deadlocks in
InnoDB
user transactions is recorded in the
mysqld
error
log. Otherwise, you see information about only the last
deadlock, using the SHOW ENGINE INNODB
STATUS
command. An occasional
InnoDB
deadlock is not necessarily an
issue, because InnoDB
detects the condition
immediately, and rolls back one of the transactions
automatically. You might use this option to troubleshoot why
deadlocks are happening if an application does not have
appropriate error-handling logic to detect the rollback and
retry its operation. A large number of deadlocks might
indicate the need to restructure transactions that issue
DML or SELECT ... FOR
UPDATE
statements for multiple tables, so that each
transaction accesses the tables in the same order, thus
avoiding the deadlock condition.
Introduced | 5.5.4 | ||
Command-Line Format | --innodb_purge_batch_size=# | ||
Option-File Format | innodb_purge_batch_size | ||
System Variable Name | innodb_purge_batch_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (>= 5.5.4) | |||
Type | numeric | ||
Default | 20 | ||
Range | 1 .. 5000 |
The granularity of changes, expressed in units of
redo log records, that
trigger a purge operation,
flushing the changed buffer
pool blocks to disk. The default value is 20, and the
range is 1-5000. This option is intended for tuning
performance in combination with the setting
innodb_purge_threads=1
, and typical users
do not need to modify it.
Introduced | 5.5.4 | ||
Command-Line Format | --innodb_purge_threads=# | ||
Option-File Format | innodb_purge_threads | ||
System Variable Name | innodb_purge_threads | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (>= 5.5.4) | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 1 |
The number of background threads devoted to the InnoDB purge operation. Currently, can only be 0 (the default) or 1. The default value of 0 signifies that the purge operation is performed as part of the master thread. Running the purge operation in its own thread can reduce internal contention within InnoDB, improving scalability. Currently, the performance gain might be minimal because the background thread might encounter different kinds of contention than before. This feature primarily lays the groundwork for future performance work.
Introduced | 5.5.16 | ||
Command-Line Format | --innodb_random_read_ahead=# | ||
Option-File Format | innodb_random_read_ahead | ||
System Variable Name | innodb_random_read_ahead | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Enables the random
read-ahead technique
for optimizing InnoDB
I/O. This is a
setting that was originally on by default, then was removed in
MySQL 5.5, and now is available but turned off by default. See
Section 14.3.16.2.7, “Changes in the Read-Ahead Algorithm” for details
about the performance considerations for the different types
of read-ahead requests. For general I/O tuning advice, see
Section 8.5.7, “Optimizing InnoDB
Disk I/O”.
Command-Line Format | --innodb_read_ahead_threshold=# | ||
Option-File Format | innodb_read_ahead_threshold | ||
System Variable Name | innodb_read_ahead_threshold | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 56 | ||
Range | 0 .. 64 |
Controls the sensitivity of linear
read-ahead that
InnoDB
uses to prefetch pages into the
buffer pool. If
InnoDB
reads at least
innodb_read_ahead_threshold
pages sequentially from an
extent (64 pages), it
initiates an asynchronous read for the entire following
extent. The permissible range of values is 0 to 64. The
default is 56: InnoDB
must read at least 56
pages sequentially from an extent to initiate an asynchronous
read for the following extent. See
Section 14.3.16.2.7, “Changes in the Read-Ahead Algorithm” for more
information.
Command-Line Format | --innodb_read_io_threads=# | ||
Option-File Format | innodb_read_io_threads | ||
System Variable Name | innodb_read_io_threads | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 4 | ||
Range | 1 .. 64 |
The number of I/O threads for read operations in
InnoDB
. The default value is 4. See
Section 14.3.16.2.8, “Multiple Background InnoDB I/O Threads” for
more information. For general I/O tuning advice, see
Section 8.5.7, “Optimizing InnoDB
Disk I/O”.
On Linux systems, running multiple MySQL servers (typically
more than 12) with default settings for
innodb_read_io_threads
,
innodb_write_io_threads
,
and the Linux aio-max-nr
setting can
exceed system limits. Ideally, increase the
aio-max-nr
setting; as a workaround, you
might reduce the settings for one or both of the MySQL
configuration options.
Command-Line Format | --innodb_replication_delay=# | ||
Option-File Format | innodb_replication_delay | ||
System Variable Name | innodb_replication_delay | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 |
The replication thread delay (in ms) on a slave server if
innodb_thread_concurrency
is
reached.
Command-Line Format | --innodb_rollback_on_timeout | ||
Option-File Format | innodb_rollback_on_timeout | ||
System Variable Name | innodb_rollback_on_timeout | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
In MySQL 5.5, InnoDB
rolls back only the last
statement on a transaction timeout by default. If
--innodb_rollback_on_timeout
is
specified, a transaction timeout causes
InnoDB
to abort and roll back the entire
transaction (the same behavior as in MySQL 4.1).
Introduced | 5.5.11 | ||
Command-Line Format | --innodb_rollback_segments=# | ||
Option-File Format | innodb_rollback_segments | ||
System Variable Name | innodb_rollback_segments | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 128 | ||
Range | 1 .. 128 |
Defines how many of the rollback segments in the system tablespace that InnoDB uses within a transaction. You might reduce this value from its default of 128 if a smaller number of rollback segments performs better for your workload.
Command-Line Format | --innodb_spin_wait_delay=# | ||
Option-File Format | innodb_spin_wait_delay | ||
System Variable Name | innodb_spin_wait_delay | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 6 | ||
Range | 0 .. 4294967295 |
The maximum delay between polls for a spin lock. The low-level implementation of this mechanism varies depending on the combination of hardware and operating system, so the delay does not correspond to a fixed time interval. The default value is 6. See Section 14.3.16.2.14, “Control of Spin Lock Polling” for more information.
Introduced | 5.5.10 | ||
Command-Line Format | --innodb_stats_method=name | ||
Option-File Format | innodb_stats_method | ||
System Variable Name | innodb_stats_method | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | nulls_equal | ||
Valid Values | nulls_equal | ||
nulls_unequal | |||
nulls_ignored |
How the server treats NULL
values when
collecting statistics
about the distribution of index values for
InnoDB
tables. This variable has three
possible values, nulls_equal
,
nulls_unequal
, and
nulls_ignored
. For
nulls_equal
, all NULL
index values are considered equal and form a single value
group that has a size equal to the number of
NULL
values. For
nulls_unequal
, NULL
values are considered unequal, and each
NULL
forms a distinct value group of size
1. For nulls_ignored
,
NULL
values are ignored.
The method that is used for generating table statistics
influences how the optimizer chooses indexes for query
execution, as described in
Section 8.3.7, “InnoDB
and MyISAM
Index Statistics
Collection”.
Introduced | 5.5.4 | ||
Command-Line Format | --innodb_stats_on_metadata | ||
Option-File Format | innodb_stats_on_metadata | ||
System Variable Name | innodb_stats_on_metadata | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
When this variable is enabled (which is the default, as before
the variable was created), InnoDB
updates
statistics during
metadata statements such as SHOW TABLE
STATUS
or SHOW INDEX
,
or when accessing the INFORMATION_SCHEMA
tables TABLES
or
STATISTICS
. (These updates are
similar to what happens for ANALYZE
TABLE
.) When disabled, InnoDB
does not update statistics during these operations. Disabling
this variable can improve access speed for schemas that have a
large number of tables or indexes. It can also improve the
stability of
execution
plans for queries that involve
InnoDB
tables.
Command-Line Format | --innodb_stats_sample_pages=# | ||
Option-File Format | innodb_stats_sample_pages | ||
System Variable Name | innodb_stats_sample_pages | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 8 | ||
Range | 1 .. 2**64-1 |
The number of index pages to sample for index distribution
statistics such as are
calculated by ANALYZE TABLE
.
The default value is 8. See
Section 14.3.6.5, “Controlling Optimizer Statistics Estimation”
for more information.
Command-Line Format | --innodb_strict_mode=# | ||
Option-File Format | innodb_strict_mode | ||
System Variable Name | innodb_strict_mode | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Whether InnoDB
returns errors rather than
warnings for certain conditions. This is analogous to strict
SQL mode. The default value is OFF
. See
Section 14.3.6.4, “InnoDB
Strict Mode” for a list
of the conditions that are affected.
Command-Line Format | --innodb_support_xa | ||
Option-File Format | innodb_support_xa | ||
System Variable Name | innodb_support_xa | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
Enables InnoDB
support for two-phase commit
in XA transactions, causing an
extra disk flush for transaction preparation. This setting is
the default. The XA mechanism is used internally and is
essential for any server that has its binary log turned on and
is accepting changes to its data from more than one thread. If
you turn it off, transactions can be written to the binary log
in a different order from the one in which the live database
is committing them. This can produce different data when the
binary log is replayed in disaster recovery or on a
replication slave. Do not turn it off on a replication master
server unless you have an unusual setup where only one thread
is able to change data.
For a server that is accepting data changes from only one
thread, it is safe and recommended to turn off this option to
improve performance for InnoDB
tables. For example, you can turn it off on replication slaves
where only the replication SQL thread is changing data.
You can also turn off this option if you do not need it for safe binary logging or replication, and you also do not use an external XA transaction manager.
Command-Line Format | --innodb_sync_spin_loops=# | ||
Option-File Format | innodb_sync_spin_loops | ||
System Variable Name | innodb_sync_spin_loops | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 30 | ||
Range | 0 .. 4294967295 |
The number of times a thread waits for an
InnoDB
mutex to be freed before the thread
is suspended. The default value is 30.
Command-Line Format | --innodb_table_locks | ||
Option-File Format | innodb_table_locks | ||
System Variable Name | innodb_table_locks | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
If autocommit = 0
,
InnoDB
honors LOCK
TABLES
; MySQL does not return from LOCK
TABLES ... WRITE
until all other threads have
released all their locks to the table. The default value of
innodb_table_locks
is 1,
which means that LOCK TABLES
causes InnoDB to lock a table internally if
autocommit = 0
.
As of MySQL 5.5.3, innodb_table_locks =
0
has no effect for tables locked explicitly with
LOCK TABLES ...
WRITE
. It still has an effect for tables locked for
read or write by
LOCK TABLES ...
WRITE
implicitly (for example, through triggers) or
by LOCK TABLES
... READ
.
Command-Line Format | --innodb_thread_concurrency=# | ||
Option-File Format | innodb_thread_concurrency | ||
System Variable Name | innodb_thread_concurrency | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 1000 |
InnoDB
tries to keep the number of
operating system threads concurrently inside
InnoDB
less than or equal to the limit
given by this variable. Once the number of threads reaches
this limit, additional threads are placed into a wait state
within a FIFO queue for execution. Threads waiting for locks
are not counted in the number of concurrently executing
threads.
The correct value for this variable is dependent on environment and workload. Try a range of different values to determine what value works for your applications. A recommended value is 2 times the number of CPUs plus the number of disks.
The range of this variable is 0 to 1000. A value of 0 (the
default) is interpreted as infinite concurrency (no
concurrency checking). Disabling thread concurrency checking
enables InnoDB to create as many threads as it needs. A value
of 0 also disables the queries inside
InnoDB
and queries in queue
counters
in the ROW OPERATIONS
section of SHOW ENGINE INNODB STATUS
output.
Command-Line Format | --innodb_thread_sleep_delay=# | ||
Option-File Format | innodb_thread_sleep_delay | ||
System Variable Name | innodb_thread_sleep_delay | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 10000 |
How long InnoDB
threads sleep before
joining the InnoDB
queue, in microseconds.
The default value is 10,000. A value of 0 disables sleep.
Introduced | 5.5.4 | ||
Command-Line Format | --innodb_use_native_aio=# | ||
Option-File Format | innodb_use_native_aio | ||
System Variable Name | innodb_use_native_aio | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
Specifies whether to use the Linux asynchronous I/O subsystem. This variable applies to Linux systems only, and cannot be changed while the server is running.
Normally, you do not need to touch this option, because it is
enabled by default. If a problem with the asynchronous I/O
subsystem in the OS prevents InnoDB
from
starting, start the server with this variable disabled (use
innodb_use_native_aio=0
in
the option file). This option could also be turned off
automatically during startup, if InnoDB
detects a potential problem such as a combination of
tmpdir
location, tmpfs
filesystem, and Linux kernel that that does not support AIO on
tmpfs
.
This variable was added in MySQL 5.5.4.
Command-Line Format | --innodb_use_sys_malloc=# | ||
Option-File Format | innodb_use_sys_malloc | ||
System Variable Name | innodb_use_sys_malloc | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
Whether InnoDB
uses the operating system
memory allocator (ON
) or its own
(OFF
). The default value is
ON
. See
Section 14.3.16.2.3, “Using Operating System Memory Allocators” for more
information.
The InnoDB
version number. Starting in
5.5.30, the separate numbering for InnoDB
is discontinued and this value is the same as for the
version
variable.
Command-Line Format | --innodb_write_io_threads=# | ||
Option-File Format | innodb_write_io_threads | ||
System Variable Name | innodb_write_io_threads | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 4 | ||
Range | 1 .. 64 |
The number of I/O threads for write operations in
InnoDB
. The default value is 4. See
Section 14.3.16.2.8, “Multiple Background InnoDB I/O Threads” for
more information. For general I/O tuning advice, see
Section 8.5.7, “Optimizing InnoDB
Disk I/O”.
On Linux systems, running multiple MySQL servers (typically
more than 12) with default settings for
innodb_read_io_threads
,
innodb_write_io_threads
,
and the Linux aio-max-nr
setting can
exceed system limits. Ideally, increase the
aio-max-nr
setting; as a workaround, you
might reduce the settings for one or both of the MySQL
configuration options.
Command-Line Format | --sync-binlog=# | ||
Option-File Format | sync_binlog | ||
System Variable Name | sync_binlog | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 18446744073709547520 |
If the value of this variable is greater than 0, the MySQL
server synchronizes its binary log to disk (using
fdatasync()
) after every
sync_binlog
writes to the
binary log. There is one write to the binary log per statement
if autocommit is enabled, and one write per transaction
otherwise. The default value of
sync_binlog
is 0, which does
no synchronizing to disk. A value of 1 is the safest choice,
because in the event of a crash you lose at most one statement
or transaction from the binary log. However, it is also the
slowest choice (unless the disk has a battery-backed cache,
which makes synchronization very fast).
User Comments
Be careful when being too aggressive with settings like innodb_buffer_pool_size. Although your system might have a lot of RAM installed, a 32-bit Linux operating can't allocate more than 2.2-2.7G* per process.
* This limit varies in different kernels.
I am using innodb_file_per_table to separate the files out so when i delete database, we can get our disk usage back. I go into details in my blog which I hope helps somebody.
http://crazytoon.com/2007/04/03/mysql-ibdata-files-do-not-shrink-on-database-deletion-innodb/
Commentary on Innodb parameters for an 8way machine:
http://krow.livejournal.com/542306.html
Changing innodb_log_file_size can yield strange errors, such as: Incorrect information in file: './db010840/notifications.frm'
This is particularly of importance when performing a file based sync to setup replication. If you have a different (or no) innodb_log_file_size setting at the slave, you will be puzzled for hours (I was).
NOTE: The time to Initialise the innodb buffer pool is roughly proportional to the size of the pool created. On large installations[*] this initialisation time may be significant.
[*] 2009/10 Initialising a 10 GB buffer pool takes 6 seconds, larger configurations may take proportionally longer.
It would have been better if the parameters given in here were with concrete examples. I hope it would be done in the future releases.
Add your own comment.