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. For more information on specifying options and
system variables, see Section 4.2.3, “Specifying Program Options”. Many of
the system variables can be changed at runtime (see
Section 5.1.5.2, “Dynamic System Variables”).
var_name
=value
MySQL Enterprise. The MySQL Enterprise Monitor provides expert advice on InnoDB start-up options and related system variables. For more information, see http://www.mysql.com/products/enterprise/advisors.html.
Table 13.2. InnoDB Option/Variable Reference
InnoDB
command options:
Enables the InnoDB
storage engine, if the
server was compiled with InnoDB
support.
Use
--skip-innodb
to disable InnoDB
.
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.
InnoDB
system variables:
Version Introduced | 5.0.52 | |
Command-Line Format | --innodb_adaptive_hash_index=# |
|
Config-File Format | innodb_adaptive_hash_index |
|
Option Sets Variable | Yes, innodb_adaptive_hash_index
|
|
Variable Name | innodb_adaptive_hash_index |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | boolean |
|
Default | ON |
Whether InnoDB adaptive hash indexes are enabled or disabled
(see Section 13.2.10.4, “Adaptive Hash Indexes”). This variable is
enabled by default. Use
--skip-innodb_adaptive_hash_index
at server
startup to disable it. This variable was added in MySQL
5.0.52.
innodb_additional_mem_pool_size
Command-Line Format | --innodb_additional_mem_pool_size=# |
|
Config-File Format | innodb_additional_mem_pool_size |
|
Option Sets Variable | Yes, innodb_additional_mem_pool_size
|
|
Variable Name | innodb_additional_mem_pool_size |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | numeric |
|
Default | 1048576 |
|
Range | 524288-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
1MB.
Command-Line Format | --innodb_autoextend_increment=# |
|
Config-File Format | innodb_autoextend_increment |
|
Option Sets Variable | Yes, innodb_autoextend_increment
|
|
Variable Name | innodb_autoextend_increment |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | numeric |
|
Default | 8 |
|
Range | 1-1000 |
The increment size (in MB) for extending the size of an auto-extending tablespace file when it becomes full. The default value is 8.
Command-Line Format | --innodb_buffer_pool_awe_mem_mb=# |
|
Config-File Format | innodb_buffer_pool_awe_mem_mb |
|
Option Sets Variable | Yes, innodb_buffer_pool_awe_mem_mb
|
|
Variable Name | innodb_buffer_pool_awe_mem_mb |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Platform Specific | windows | |
Permitted Values | ||
Type (windows) | numeric |
|
Default | 0 |
|
Range | 0-63000 |
The size of the buffer pool (in MB), if it is placed in the
AWE memory. If it is greater than 0,
innodb_buffer_pool_size
is
the window in the 32-bit address space of
mysqld where InnoDB
maps
that AWE memory. A good value for
innodb_buffer_pool_size
is
500MB. The maximum possible value is 63000.
To take advantage of AWE memory, you will need to recompile
MySQL yourself. The current project settings needed for doing
this can be found in the
innobase/os/os0proc.c
source file.
This variable is relevant only in 32-bit Windows. If your
32-bit Windows operating system supports more than 4GB memory,
using so-called “Address Windowing Extensions,”
you can allocate the InnoDB
buffer pool
into the AWE physical memory using this variable.
Command-Line Format | --innodb_buffer_pool_size=# |
|
Config-File Format | innodb_buffer_pool_size |
|
Option Sets Variable | Yes, innodb_buffer_pool_size
|
|
Variable Name | innodb_buffer_pool_size |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Platform Specific | windows | |
Permitted Values | ||
Type (windows) | numeric |
|
Default | 8388608 |
|
Range | 1048576-4294967295 |
The size in bytes of the memory buffer
InnoDB
uses to cache data and indexes of
its tables. The default value is 8MB. 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. However, do not set it
too large because competition for physical memory might cause
paging in the operating system. Also, 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 7.4.6, “The InnoDB
Buffer Pool”
Version Introduced | 5.0.3 | |
Command-Line Format | --innodb_checksums |
|
Config-File Format | innodb_checksums |
|
Option Sets Variable | Yes, innodb_checksums
|
|
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
. This variable was
added in MySQL 5.0.3.
Version Introduced | 5.0.12 | |
Command-Line Format | --innodb_commit_concurrency=# |
|
Config-File Format | innodb_commit_concurrency |
|
Option Sets Variable | Yes, innodb_commit_concurrency
|
|
Variable Name | innodb_commit_concurrency |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | numeric |
|
Default | 0 |
|
Range | 0-100 |
The number of threads that can commit at the same time. A value of 0 (the default) allows any number of transactions to commit simultaneously. This variable was added in MySQL 5.0.12.
Version Introduced | 5.0.3 | |
Command-Line Format | --innodb_concurrency_tickets=# |
|
Config-File Format | innodb_concurrency_tickets |
|
Option Sets Variable | Yes, innodb_concurrency_tickets
|
|
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 allowed 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. This
variable was added in MySQL 5.0.3.
Command-Line Format | --innodb_data_file_path=name |
|
Config-File Format | innodb_data_file_path |
|
Variable Name | innodb_data_file_path |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | filename |
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
10MB. If you do not specify
innodb_data_file_path
, the
default behavior is to create a single 10MB auto-extending
data file 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 13.2.2, “InnoDB
Configuration”.
Command-Line Format | --innodb_data_home_dir=name |
|
Config-File Format | innodb_data_home_dir |
|
Option Sets Variable | Yes, innodb_data_home_dir
|
|
Variable Name | innodb_data_home_dir |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | filename |
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
.
Version Introduced | 5.0.3 | |
Command-Line Format | --innodb-doublewrite |
|
Config-File Format | innodb_doublewrite |
|
Option Sets Variable | Yes, innodb_doublewrite
|
|
Variable Name | innodb_doublewrite |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | numeric |
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. This variable was added
in MySQL 5.0.3.
Command-Line Format | --innodb_fast_shutdown[=#] |
|
Config-File Format | innodb_fast_shutdown |
|
Option Sets Variable | Yes, innodb_fast_shutdown
|
|
Variable Name | innodb_fast_shutdown |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | boolean |
|
Default | 1 |
|
Valid Values |
0 , 1 , 2
|
The InnoDB
shutdown mode. By default, the
value is 1, which causes a “fast” shutdown (the
normal type of shutdown). If the value is 0,
InnoDB
does a full purge and an insert
buffer merge before a shutdown. These operations can take
minutes, or even hours in extreme cases. If the value is 1,
InnoDB
skips these operations at shutdown.
If the value is 2, InnoDB
will just flush
its logs and then shut down cold, as if MySQL had crashed; no
committed transaction will be lost, but crash recovery will be
done at the next startup. The value of 2 can be used as of
MySQL 5.0.5, except that it cannot be used on NetWare.
Command-Line Format | --innodb_file_io_threads=# |
|
Config-File Format | innodb_file_io_threads |
|
Option Sets Variable | Yes, innodb_file_io_threads
|
|
Variable Name | innodb_file_io_threads |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | numeric |
|
Default | 4 |
|
Range | 4-64 |
The number of file I/O threads in InnoDB
.
Normally, this should be left at the default value of 4, but
disk I/O on Windows may benefit from a larger number. On Unix,
increasing the number has no effect; InnoDB
always uses the default value.
Command-Line Format | --innodb_file_per_table |
|
Config-File Format | innodb_file_per_table |
|
Variable Name | innodb_file_per_table |
|
Variable Scope | Global | |
Dynamic Variable | No |
If innodb_file_per_table
is
disabled (the default), InnoDB
creates
tables in the shared 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 shared tablespace. See
Section 13.2.2.1, “Using Per-Table Tablespaces”.
innodb_flush_log_at_trx_commit
Command-Line Format | --innodb_flush_log_at_trx_commit[=#] |
|
Config-File Format | innodb_flush_log_at_trx_commit |
|
Option Sets Variable | Yes, innodb_flush_log_at_trx_commit
|
|
Variable Name | innodb_flush_log_at_trx_commit |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | numeric |
|
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 the value required for ACID
compliance. You can achieve better performance by setting the
value different from 1, but then you can lose at most 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, then only an
operating system crash or a power outage can erase the last
second of transactions. However, InnoDB
's
crash recovery is not affected and thus crash recovery does
work regardless of the value.
For the greatest possible durability and consistency in a
replication setup using InnoDB
with
transactions, you should use
innodb_flush_log_at_trx_commit=1
,
sync_binlog=1
, and, before MySQL 5.0.3,
innodb_safe_binlog
in your master server
my.cnf
file.
(innodb_safe_binlog
is not needed from
5.0.3 on.)
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 |
|
Config-File Format | innodb_flush_method |
|
Option Sets Variable | Yes, innodb_flush_method
|
|
Variable Name | innodb_flush_method |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type (windows) | enumeration |
|
Default | async_unbuffered |
If set to fdatasync
(the default),
InnoDB
uses fsync()
to
flush both the data and log files. If 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.
Different values of this variable can have a marked effect on
InnoDB
performance. For example, on some
systems where InnoDB
data and log files are
located on a SAN, it has been found that setting
innodb_flush_method
to
O_DIRECT
can degrade performance of simple
SELECT
statements by a factor
of three.
Command-Line Format | --innodb_force_recovery=# |
|
Config-File Format | innodb_force_recovery |
|
Option Sets Variable | Yes, innodb_force_recovery
|
|
Variable Name | innodb_force_recovery |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | enumeration |
|
Default | 0 |
|
Valid Values |
0 , SRV_FORCE_IGNORE_CORRUPT , SRV_FORCE_NO_BACKGROUND , SRV_FORCE_NO_TRX_UNDO , SRV_FORCE_NO_IBUF_MERGE , SRV_FORCE_NO_UNDO_LOG_SCAN , SRV_FORCE_NO_LOG_REDO
|
The crash recovery mode. Possible values are from 0 to 6. The
meanings of these values are described in
Section 13.2.6.2, “Forcing InnoDB
Recovery”.
This variable should be set greater than 0 only in an
emergency situation when you want 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.
Command-Line Format | --innodb_lock_wait_timeout=# |
|
Config-File Format | innodb_lock_wait_timeout |
|
Option Sets Variable | Yes, innodb_lock_wait_timeout
|
|
Variable Name | innodb_lock_wait_timeout |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | numeric |
|
Default | 50 |
|
Range | 1-1073741824 |
The timeout in seconds an InnoDB
transaction may wait 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 will hang for at most
this many seconds 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 not
executed. The current transaction is not
rolled back. (Until MySQL 5.0.13 InnoDB
rolled back the entire transaction if a lock wait timeout
happened. You can restore this behavior by starting the server
with the
--innodb_rollback_on_timeout
option, available as of MySQL 5.0.32. See also
Section 13.2.12, “InnoDB
Error Handling”.)
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.
InnoDB
does detect transaction deadlocks in
its own lock table immediately and rolls back one transaction.
The lock wait timeout value does not apply to such a wait.
innodb_locks_unsafe_for_binlog
Command-Line Format | --innodb_locks_unsafe_for_binlog |
|
Config-File Format | innodb_locks_unsafe_for_binlog |
|
Option Sets Variable | Yes, innodb_locks_unsafe_for_binlog
|
|
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 13.2.8.4, “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 12.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 13.2.8.5, “Avoiding the Phantom Problem Using Next-Key Locking”.
Starting from MySQL 5.0.2, enabling
innodb_locks_unsafe_for_binlog
has an additional effect. 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. Note that
enabling this variable still does not allow operations such as
UPDATE
to overtake other
similar operations (such as another
UPDATE
) even when they affect
different rows.
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 13.2.10.1, “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)
The second UPDATE
proceeds part
way before it blocks. It begins acquiring x-locks, and blocks
when it tries to acquire one for a row still locked by first
UPDATE
. The second
UPDATE
does not proceed until
the first UPDATE
commits or
rolls back:
x-lock(1,2); update(1,2) to (1,4); retain x-lock x-lock(2,3); block and wait for first UPDATE to commit or roll back
In this case, the second UPDATE
must wait for a commit or rollback of the first
UPDATE
, even though it affects
different rows. The first
UPDATE
has an exclusive lock on
row (2,3) that it has not released. As the second
UPDATE
scans rows, it tries to
acquire an exclusive lock for that same row, which it cannot
have.
This variable is unused, and is deprecated as of MySQL 5.0.24. It will be removed in MySQL 5.1
Whether to log InnoDB
archive files. This
variable is present for historical reasons, but is unused.
Recovery from a backup is done by MySQL using its own log
files, so there is no need to archive
InnoDB
log files. The default for this
variable is 0.
Command-Line Format | --innodb_log_buffer_size=# |
|
Config-File Format | innodb_log_buffer_size |
|
Option Sets Variable | Yes, innodb_log_buffer_size
|
|
Variable Name | innodb_log_buffer_size |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | numeric |
|
Default | 1048576 |
|
Range | 1048576-4294967295 |
The size in bytes of the buffer that InnoDB
uses to write to the log files on disk. The default value is
1MB. Sensible values range from 1MB to 8MB. A large log buffer
allows 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=# |
|
Config-File Format | innodb_log_file_size |
|
Option Sets Variable | Yes, innodb_log_file_size
|
|
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 must be less than 4GB. 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=# |
|
Config-File Format | innodb_log_files_in_group |
|
Option Sets Variable | Yes, innodb_log_files_in_group
|
|
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=name |
|
Config-File Format | innodb_log_group_home_dir |
|
Option Sets Variable | Yes, innodb_log_group_home_dir
|
|
Variable Name | innodb_log_group_home_dir |
|
Variable Scope | Global | |
Dynamic Variable | No | |
Permitted Values | ||
Type | filename |
The directory path to the InnoDB
log files.
If you do not specify any InnoDB
log
variables, the default is to create two 5MB files names
ib_logfile0
and
ib_logfile1
in the MySQL data directory.
Command-Line Format | --innodb_max_dirty_pages_pct=# |
|
Config-File Format | innodb_max_dirty_pages_pct |
|
Option Sets Variable | Yes, innodb_max_dirty_pages_pct
|
|
Variable Name | innodb_max_dirty_pages_pct |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | numeric |
|
Default | 90 |
|
Range | 0-100 |
This is an integer in the range from 0 to 100. The default
value is 90. 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=# |
|
Config-File Format | innodb_max_purge_lag |
|
Option Sets Variable | Yes, innodb_max_purge_lag
|
|
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 13.2.9, “InnoDB
Multi-Versioning”). The default value
0 (no delays).
The InnoDB
transaction system maintains a
list of transactions that have delete-marked index records 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 allowable 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
The number of identical copies of log groups to keep for the database. This should be set to 1.
Command-Line Format | --innodb_open_files=# |
|
Config-File Format | innodb_open_files |
|
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 tablespaces
in InnoDB
. It specifies the maximum number
of .ibd
files that
InnoDB
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
only. They are independent
of those specified by the
--open-files-limit
server
option, and do not affect the operation of the table cache.
Version Introduced | 5.0.32 | |
Command-Line Format | --innodb_rollback_on_timeout |
|
Config-File Format | innodb_rollback_on_timeout |
|
Option Sets Variable | Yes, innodb_rollback_on_timeout
|
|
Variable Name | innodb_rollback_on_timeout |
|
Variable Scope | Global | |
Dynamic Variable | No |
In MySQL 5.0.13 and up, 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 before MySQL 5.0.13). This
variable was added in MySQL 5.0.32.
innodb_safe_binlog
Version Removed | 5.0.3 | |
Version Deprecated | 5.0.3 | |
Command-Line Format | --innodb_safe_binlog |
|
Config-File Format | innodb_safe_binlog |
|
Deprecated | 5.0.3 | |
Permitted Values | ||
Type | boolean |
If this option is given, then after a crash recovery by
InnoDB
, mysqld truncates
the binary log after the last not-rolled-back transaction in
the log. The option also causes InnoDB
to
print an error if the binary log is smaller or shorter than it
should be. See Section 5.2.3, “The Binary Log”. This variable was
removed in MySQL 5.0.3, having been made obsolete by the
introduction of XA transaction support. You should set
innodb_support_xa
to
ON
or 1 to ensure consistency. See
innodb_support_xa
.
Version Introduced | 5.0.3 | |
Command-Line Format | --innodb_support_xa |
|
Config-File Format | innodb_support_xa |
|
Option Sets Variable | Yes, innodb_support_xa
|
|
Variable Name | innodb_support_xa |
|
Variable Scope | Both | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | boolean |
|
Default | TRUE |
When the variable is enabled (the default),
InnoDB
support for two-phase commit in XA
transactions is enabled, which causes an extra disk flush for
transaction preparation.
If you do not wish to use XA transactions, you can disable
this variable to reduce the number of disk flushes and get
better InnoDB
performance.
Having innodb_support_xa
enabled on a replication master — or on any MySQL server
where binary logging is in use — ensures that the binary
log does not get out of sync compared to the table data.
This variable was added in MySQL 5.0.3.
Version Introduced | 5.0.3 | |
Command-Line Format | --innodb_sync_spin_loops=# |
|
Config-File Format | innodb_sync_spin_loops |
|
Option Sets Variable | Yes, innodb_sync_spin_loops
|
|
Variable Name | innodb_sync_spin_loops |
|
Variable Scope | Global | |
Dynamic Variable | Yes |
The number of times a thread waits for an
InnoDB
mutex to be freed before the thread
is suspended. The default value is 20. This variable was added
in MySQL 5.0.3.
Command-Line Format | --innodb_table_locks |
|
Config-File Format | innodb_table_locks |
|
Option Sets Variable | Yes, innodb_table_locks
|
|
Variable Name | innodb_table_locks |
|
Variable Scope | Both | |
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
.
Command-Line Format | --innodb_thread_concurrency=# |
|
Config-File Format | innodb_thread_concurrency |
|
Option Sets Variable | Yes, innodb_thread_concurrency
|
|
Variable Name | innodb_thread_concurrency |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values (>= 5.0.9) | ||
Type | numeric |
|
Default | 20 |
|
Range | 1-1000 |
|
Permitted Values (>= 5.0.19) | ||
Type | numeric |
|
Default | 8 |
|
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. You will need to 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 20 or higher is interpreted as infinite concurrency before MySQL 5.0.19. From 5.0.19 on, you can disable thread concurrency checking by setting the value to 0. Disabling thread concurrency checking allows InnoDB to create as many threads as it needs.
The default value has changed several times: 8 before MySQL 5.0.8, 20 (infinite) from 5.0.8 through 5.0.18, 0 (infinite) from 5.0.19 to 5.0.20, and 8 (finite) from 5.0.21 on.
Version Introduced | 5.0.3 | |
Command-Line Format | --innodb_thread_sleep_delay=# |
|
Config-File Format | innodb_thread_sleep_delay |
|
Option Sets Variable | Yes, innodb_thread_sleep_delay
|
|
Variable Name | innodb_thread_sleep_delay |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values (>= 5.0.8, <= 5.0.18) | ||
Type | numeric |
|
Default | 0 |
|
Range | 1000-4294967295 |
|
Permitted Values (>= 5.0.19, <= 5.0.20) | ||
Type | numeric |
|
Default | 0 |
|
Range | 1000-4294967295 |
|
Permitted Values (>= 5.0.21) | ||
Type | numeric |
|
Default | 8 |
How long InnoDB
threads sleep before
joining the InnoDB
queue, in microseconds.
The default value is 10,000. A value of 0 disables sleep. This
variable was added in MySQL 5.0.3.
innodb_use_legacy_cardinality_algorithm
Version Introduced | 5.0.82 | |
Command-Line Format | --innodb_use_legacy_cardinality_algorithm=# |
|
Config-File Format | innodb_use_legacy_cardinality_algorithm |
|
Option Sets Variable | Yes, innodb_use_legacy_cardinality_algorithm
|
|
Variable Name | innodb_use_legacy_cardinality_algorithm |
|
Variable Scope | Global | |
Dynamic Variable | Yes | |
Permitted Values | ||
Type | boolean |
|
Default | ON |
InnoDB
uses random numbers to
generate dives into indexes for calculating index cardinality.
However, under certain conditions, the algorithm does not
generate random numbers, so ANALYZE
TABLE
sometimes does not update cardinality
estimates properly. An alternative algorithm was introduced in
MySQL 5.0.82 with better randomization properties, and the
innodb_use_legacy_cardinality_algorithm
,
system variable which algorithm to use. The default value of
the variable is 1 (ON
), to use the original
algorithm for compatibility with existing applications. The
variable can be set to 0 (OFF
) to use the
new algorithm with improved randomness.
Version Introduced | 5.0.1 | |
Command-Line Format | --sync-binlog=# |
|
Config-File Format | sync_binlog |
|
Option Sets Variable | Yes, sync_binlog
|
|
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.
Add your own comment.