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 disableInnoDBchecksums, you can use--innodb_checksumsor--skip-innodb_checksumson the command line, orinnodb_checksumsorskip-innodb_checksumsin an option file.System variables that take a numeric value can be specified as
--on the command line or asvar_name=valuein option files.var_name=valueMany system variables can be changed at runtime (see Section 5.1.6.2, “Dynamic System Variables”).
For information about
GLOBALandSESSIONvariable scope modifiers, refer to theSETstatement documentation.Certain options control the locations and layout of the
InnoDBdata files. Section 14.9.1, “InnoDB Startup Configuration” explains how to use these options.Some options, which you might not use initially, help tune
InnoDBperformance characteristics based on machine capacity and your database workload.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-innodbSystem Variable Name ignore_builtin_innodbVariable 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
InnoDBwere not present, which enabled theInnoDB Pluginto be used instead. In MySQL 5.5,InnoDBis the default storage engine andInnoDB Pluginis not used, so this option has no effect. As of MySQL 5.5.22, it is deprecated and its use results in a warning. -
Command-Line Format --innodb[=value]Permitted Values Type enumeration Default ONValid Values OFFONFORCEControls loading of the
InnoDBstorage engine, if the server was compiled withInnoDBsupport. This option has a tristate format, with possible values ofOFF,ON, orFORCE. See Section 5.5.2, “Installing and Uninstalling Plugins”.To disable
InnoDB, use--innodb=OFFor--skip-innodb. In this case, because the default storage engine isInnoDB, the server does not start unless you also use--default-storage-engineto set the default to some other engine. -
Command-Line Format --innodb-status-filePermitted Values Type boolean Default OFFControls whether
InnoDBcreates a file namedinnodb_status.in the MySQL data directory. If enabled,pidInnoDBperiodically writes the output ofSHOW ENGINE INNODB STATUSto this file.By default, the file is not created. To create it, start mysqld with the
--innodb-status-file=1option. The file is deleted during normal shutdown. Disable the
InnoDBstorage engine. See the description of--innodb.
InnoDB System Variables
-
Deprecated 5.5.22 Command-Line Format --ignore-builtin-innodbSystem Variable Name ignore_builtin_innodbVariable Scope Global Dynamic Variable No Permitted Values Type boolean See the description of
--ignore-builtin-innodbunder “InnoDB Command Options” earlier in this section. -
Command-Line Format --innodb_adaptive_flushing=#System Variable Name innodb_adaptive_flushingVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default ONSpecifies whether to dynamically adjust the rate of flushing dirty pages in the
InnoDBbuffer pool based on the workload. Adjusting the flush rate dynamically is intended to avoid bursts of I/O activity. This setting is enabled by default. See Section 14.9.2.5, “Configuring InnoDB Buffer Pool Flushing” 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=#System Variable Name innodb_adaptive_hash_indexVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default ONWhether the
InnoDBadaptive hash index is enabled or disabled. It may be desirable, depending on your workload, to dynamically enable or disable adaptive hash indexing to improve query performance. Because the adaptive hash index may not be useful for all workloads, conduct benchmarks with it both enabled and disabled, using realistic workloads. See Section 14.7.3, “Adaptive Hash Index” for details.This variable is enabled by default. As of MySQL 5.5, You can modify this parameter using the
SET GLOBALstatement, without restarting the server. Changing the setting requires theSUPERprivilege. You can also use--skip-innodb_adaptive_hash_indexat server startup to disable it.Disabling the adaptive hash index empties the hash table immediately. Normal operations can continue while the hash table is emptied, and executing queries that were using the hash table access the index B-trees directly instead. When the adaptive hash index is re-enabled, the hash table is populated again during normal operation.
innodb_additional_mem_pool_sizeCommand-Line Format --innodb_additional_mem_pool_size=#System Variable Name innodb_additional_mem_pool_sizeVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 8388608Min Value 2097152Max Value 4294967295The size in bytes of a memory pool
InnoDBuses 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. IfInnoDBruns 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
InnoDBinternal memory allocator, which is unused ifinnodb_use_sys_mallocis enabled. For more information, see Section 14.9.3, “Configuring the Memory Allocator for InnoDB”.-
Command-Line Format --innodb_autoextend_increment=#System Variable Name innodb_autoextend_incrementVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 8Min Value 1Max Value 1000The increment size (in megabytes) for extending the size of an auto-extending system tablespace file when it becomes full. The default value is 8. For related information, see System Tablespace Data File Configuration, and Section 14.10.1, “Resizing the InnoDB System Tablespace”.
The
innodb_autoextend_incrementsetting does not affect file-per-table tablespace files. These files are auto-extending regardless of theinnodb_autoextend_incrementsetting. The initial extensions are by small amounts, after which extensions occur in increments of 4MB. -
Command-Line Format --innodb_autoinc_lock_mode=#System Variable Name innodb_autoinc_lock_modeVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 1Valid Values 012The lock mode to use for generating auto-increment values. Permissible values are 0, 1, or 2, for “traditional”, “consecutive”, or “interleaved”, respectively. The default setting is 1 (“consecutive”). For the characteristics of each lock mode, see InnoDB AUTO_INCREMENT Lock Modes.
-
Introduced 5.5.4 Command-Line Format --innodb_buffer_pool_instances=#System Variable Name innodb_buffer_pool_instancesVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 1Min Value 1Max Value 64The number of regions that the
InnoDBbuffer 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 only takes effect when setting
innodb_buffer_pool_sizeto a size of 1GB or more. The total size you specify is divided among all the buffer pools. For best efficiency, specify a combination ofinnodb_buffer_pool_instancesandinnodb_buffer_pool_sizeso that each buffer pool instance is at least 1GB. -
Command-Line Format --innodb_buffer_pool_size=#System Variable Name innodb_buffer_pool_sizeVariable Scope Global Dynamic Variable No Permitted Values (32-bit platforms) Type integer Default 134217728Min Value 5242880Max Value 2**32-1Permitted Values (64-bit platforms) Type integer Default 134217728Min Value 5242880Max Value 2**64-1The size in bytes of the buffer pool, the memory area where
InnoDBcaches table and index data. 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, settinginnodb_buffer_pool_instancesto a value greater than 1 can improve the scalability on a busy server.A larger buffer pool requires less disk I/O to access the same table data more than once. On a dedicated database server, you might set the buffer pool size to 80% of the machine's physical memory size. Be aware of the following potential issues when configuring buffer pool size, and be prepared to scale back the size of the buffer pool if necessary.
Competition for physical memory can cause paging in the operating system.
InnoDBreserves additional memory for buffers and control structures, so that the total allocated space is approximately 10% greater than the specified buffer pool size.Address space for the buffer pool 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 instances with large buffer pools, initialization time might be significant.
-
Command-Line Format --innodb_change_buffering=#System Variable Name innodb_change_bufferingVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.5.3) Type enumeration Default insertsValid Values insertsnonePermitted Values (>= 5.5.4) Type enumeration Default allValid Values noneinsertsdeleteschangespurgesallWhether
InnoDBperforms change buffering, an optimization that delays write operations to secondary indexes so that the I/O operations can be performed sequentially. Permitted values are described in the following table.Table 14.7 Permitted Values for innodb_change_buffering
Value Description noneDo not buffer any operations. insertsBuffer insert operations. deletesBuffer delete marking operations; strictly speaking, the writes that mark index records for later deletion during a purge operation. changesBuffer inserts and delete-marking operations. purgesBuffer the physical deletion operations that happen in the background. allThe default. Buffer inserts, delete-marking operations, and purges. For more information, see Section 14.7.2, “Change Buffer”, and Section 14.9.4, “Configuring InnoDB Change Buffering”. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.
-
Command-Line Format --innodb_change_buffering_debug=#System Variable Name innodb_change_buffering_debugVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Max Value 2Sets a debug flag for
InnoDBchange buffering. A value of 1 forces all changes to the change buffer. A value of 2 causes a crash at merge. A default value of 0 indicates that the change buffering debug flag is not set. This option is only available when debugging support is compiled in using theWITH_DEBUGCMake option. -
Command-Line Format --innodb_checksumsSystem Variable Name innodb_checksumsVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default ONInnoDBcan use checksum validation on all pages read from disk to ensure extra fault tolerance against broken hardware or data files. This validation is enabled by default. Under specialized circumstances (such as when running benchmarks) this safety feature can be disabled with--skip-innodb-checksums. -
Command-Line Format --innodb_commit_concurrency=#System Variable Name innodb_commit_concurrencyVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Min Value 0Max Value 1000The 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_concurrencycannot 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=#System Variable Name innodb_concurrency_ticketsVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 500Min Value 1Max Value 4294967295Determines the number of threads that can enter
InnoDBconcurrently. A thread is placed in a queue when it tries to enterInnoDBif the number of threads has already reached the concurrency limit. When a thread is permitted to enterInnoDB, it is given a number of “ tickets” equal to the value ofinnodb_concurrency_tickets, and the thread can enter and leaveInnoDBfreely 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 enterInnoDB. The default value is 500.With a small
innodb_concurrency_ticketsvalue, small transactions that only need to process a few rows compete fairly with larger transactions that process many rows. The disadvantage of a smallinnodb_concurrency_ticketsvalue is that large transactions must loop through the queue many times before they can complete, which extends the amount of time required to complete their task.With a large
innodb_concurrency_ticketsvalue, large transactions spend less time waiting for a position at the end of the queue (controlled byinnodb_thread_concurrency) and more time retrieving rows. Large transactions also require fewer trips through the queue to complete their task. The disadvantage of a largeinnodb_concurrency_ticketsvalue is that too many large transactions running at the same time can starve smaller transactions by making them wait a longer time before executing.With a non-zero
innodb_thread_concurrencyvalue, you may need to adjust theinnodb_concurrency_ticketsvalue up or down to find the optimal balance between larger and smaller transactions. TheSHOW ENGINE INNODB STATUSreport shows the number of tickets remaining for an executing transaction in its current pass through the queue. This data may also be obtained from theTRX_CONCURRENCY_TICKETScolumn of theINFORMATION_SCHEMA.INNODB_TRXtable.For more information, see Section 14.9.5, “Configuring Thread Concurrency for InnoDB”.
-
Command-Line Format --innodb_data_file_path=nameSystem Variable Name innodb_data_file_pathVariable Scope Global Dynamic Variable No Permitted Values Type string Default ibdata1:10M:autoextendDefines the path and file size for individual
InnoDBsystem tablespace data files. The full directory path for system tablespace data files is formed by concatenating path defined byinnodb_data_home_dirandinnodb_data_file_path. File sizes are specified KB, MB or GB (1024MB) by appendingK,MorGto the size value. If specifying the data file size in kilobytes (KB), do so in multiples of 1024. Otherwise, KB values are rounded to nearest megabyte (MB) boundary. The sum of the sizes of the files must be at least slightly larger than 10MB. If you do not specifyinnodb_data_file_path, the default behavior is to create a single auto-extending data file, slightly larger than 10MB, namedibdata1. The size limit of individual files is determined by your operating system. You can set the file size to more than 4GB on operating systems that support large files. You can also use raw disk partitions as data files. For more information about configuring system tablespace data files, see Section 14.9.1, “InnoDB Startup Configuration”. -
Command-Line Format --innodb_data_home_dir=dir_nameSystem Variable Name innodb_data_home_dirVariable Scope Global Dynamic Variable No Permitted Values Type directory name The common part of the directory path for
InnoDBsystem tablespace data files. This setting does not affect the location of file-per-table tablespaces wheninnodb_file_per_tableis enabled. The default value is the MySQLdatadirectory. If you specify the value as an empty string, you can specify an absolute file paths forinnodb_data_file_path.For related information, see Section 14.9.1, “InnoDB Startup Configuration”.
-
Command-Line Format --innodb-doublewriteSystem Variable Name innodb_doublewriteVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default ONWhen enabled (the default),
InnoDBstores all data twice, first to the doublewrite buffer, and then to the actual data files. This variable can be turned off with--skip-innodb_doublewritefor benchmarks or cases when top performance is needed rather than concern for data integrity or possible failures.For related information, see Section 14.7.7, “Doublewrite Buffer”.
-
Command-Line Format --innodb_fast_shutdown[=#]System Variable Name innodb_fast_shutdownVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 1Valid Values 012The
InnoDBshutdown mode. If the value is 0,InnoDBdoes a slow shutdown, a full purge and a change buffer merge before shutting down. If the value is 1 (the default),InnoDBskips these operations at shutdown, a process known as a fast shutdown. If the value is 2,InnoDBflushes 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=2in emergency or troubleshooting situations, to get the absolute fastest shutdown if data is at risk of corruption. -
Command-Line Format --innodb_file_format=#System Variable Name innodb_file_formatVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.5.6) Type string Default BarracudaValid Values AntelopeBarracudaPermitted Values (>= 5.5.7) Type string Default AntelopeValid Values AntelopeBarracudaEnables an
InnoDBfile format for file-per-table tablespaces. Supported file formats areAntelopeandBarracuda.Antelopeis the originalInnoDBfile format, which supportsREDUNDANTandCOMPACTrow formats forInnoDBtables.Barracudais the newer file format, which supportsCOMPRESSEDandDYNAMICrow formats.COMPRESSEDandDYNAMICrow formats enable important storage features forInnoDBtables. See Section 14.14, “InnoDB Row Storage and Row Formats”.To create tables that use
COMPRESSEDorDYNAMICrow format, theBarracudafile format andinnodb_file_per_tablemust be enabled.Changing the
innodb_file_formatsetting does not affect the file format of existingInnoDBtablespace files.For more information, see Section 14.13, “InnoDB File-Format Management”.
-
Command-Line Format --innodb_file_format_check=#System Variable (<= 5.5.4) Name innodb_file_format_checkVariable Scope Global Dynamic Variable Yes System Variable (>= 5.5.5) Name innodb_file_format_checkVariable Scope Global Dynamic Variable No Permitted Values (5.5.0) Type string Default AntelopePermitted Values (>= 5.5.1, <= 5.5.4) Type string Default BarracudaPermitted Values (>= 5.5.5) Type boolean Default ONAs of MySQL 5.5.5, this variable can be set to 1 or 0 at server startup to enable or disable whether
InnoDBchecks the file format tag in the system tablespace (for example,AntelopeorBarracuda). If the tag is checked and is higher than that supported by the current version ofInnoDB, an error occurs andInnoDBdoes not start. If the tag is not higher,InnoDBsets the value ofinnodb_file_format_maxto 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
InnoDBchecks the file format tag in the shared tablespace. If the tag is checked and is higher than that supported by the current version ofInnoDB, an error occurs andInnoDBdoes not start. If the tag is not higher,InnoDBsets the value ofinnodb_file_format_checkto the file format tag, which is the value seen at runtime.NoteDespite the default value sometimes being displayed as
ONorOFF, always use the numeric values 1 or 0 to turn this option on or off in your configuration file or command line string. -
Introduced 5.5.5 Command-Line Format --innodb_file_format_max=#System Variable Name innodb_file_format_maxVariable Scope Global Dynamic Variable Yes Permitted Values Type string Default AntelopeValid Values AntelopeBarracudaAt server startup,
InnoDBsets the value of this variable to the file format tag in the system tablespace (for example,AntelopeorBarracuda). If the server creates or opens a table with a “higher” file format, it sets the value ofinnodb_file_format_maxto that format.This variable was added in MySQL 5.5.5.
-
Command-Line Format --innodb_file_per_tableSystem Variable Name innodb_file_per_tableVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.5.6) Type boolean Default ONPermitted Values (>= 5.5.7) Type boolean Default OFFWhen
innodb_file_per_tableis disabled,InnoDBstores the data for all tables and indexes in the ibdata files that make up the system tablespace. This setting reduces the performance overhead of filesystem operations for operations such asDROP TABLEorTRUNCATE TABLE. It is most appropriate for a server environment where entire storage devices are devoted to MySQL data. Because the system tablespace never shrinks, and is shared across all databases in an instance, avoid loading huge amounts of temporary data on a space-constrained system wheninnodb_file_per_table=OFF. Set up a separate instance in such cases, so that you can drop the entire instance to reclaim the space.When
innodb_file_per_tableis enabled,InnoDBstores data and indexes for each newly created table in a separate.ibdfile, rather than in the system tablespace. The storage for theseInnoDBtables is reclaimed when the tables are dropped or truncated. This setting enables several otherInnoDBfeatures, such as table compression. See Section 14.10.4, “InnoDB File-Per-Table Tablespaces” for details about such features as well as advantages and disadvantages of using file-per-table tablespaces.Be aware that enabling
innodb_file_per_tablealso means that anALTER TABLEoperation will moveInnoDBtable from the system tablespace to an individual.ibdfile in cases whereALTER TABLErecreates the table (ALTER OFFLINE).In MySQL 5.5 and higher, the configuration parameter
innodb_file_per_tableis dynamic, and can be setONorOFFusingSET GLOBAL. Previously, the only way to set this parameter was in the MySQL configuration file (my.cnformy.ini), and changing it required shutting down and restarting the server.Dynamically changing the value of this parameter requires the
SUPERprivilege and immediately affects the operation of all connections. innodb_flush_log_at_trx_commitCommand-Line Format --innodb_flush_log_at_trx_commit[=#]System Variable Name innodb_flush_log_at_trx_commitVariable Scope Global Dynamic Variable Yes Permitted Values Type enumeration Default 1Valid Values 012Controls the balance between strict ACID compliance for commit operations, and higher performance that is possible when commit-related I/O operations are rearranged and done in batches. You can achieve better performance by changing the default value, but then you can lose up to a second of transactions in a crash.
The default value of 1 is required for full ACID compliance. With this value, the contents of the
InnoDBlog buffer are written out to the log file at each transaction commit and the log file is flushed to disk.With a value of 0, the contents of the
InnoDBlog buffer are written to the log file approximately once per second and the log file is flushed to disk. No writes from the log buffer to the log file are performed at transaction commit. Once-per-second flushing is not 100% guaranteed to happen every second, due to process scheduling issues. Because the flush to disk operation only occurs approximately once per second, you can lose up to a second of transactions with any mysqld process crash.With a value of 2, the contents of the
InnoDBlog buffer are written to the log file after each transaction commit and the log file is flushed to disk approximately once per second. Once-per-second flushing is not 100% guaranteed to happen every second, due to process scheduling issues. Because the flush to disk operation only occurs approximately once per second, you can lose up to a second of transactions in an operating system crash or a power outage.InnoDB's crash recovery works regardless of the value. Transactions are either applied entirely or erased entirely.
For the greatest possible durability and consistency in a replication setup using
InnoDBwith transactions, useinnodb_flush_log_at_trx_commit=1andsync_binlog=1in your master servermy.cnffile.CautionMany 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
InnoDBdata. 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=nameSystem Variable Name innodb_flush_methodVariable Scope Global Dynamic Variable No Permitted Values (Unix) Type string Default NULLValid Values fsynclittlesyncnosyncO_DSYNCO_DIRECTPermitted Values (Windows) Type string Default NULLValid Values async_unbufferednormalunbufferedDefines the method used to flush data to the
InnoDBdata files and log files, which can affect I/O throughput.If
innodb_flush_method=NULLon a Unix-like system, thefsyncoption is used by default. Ifinnodb_flush_method=NULLon Windows, theasync_unbufferedoption is used by default.The
innodb_flush_methodoptions for Unix-like systems include:fsync:InnoDBuses thefsync()system call to flush both the data and log files.fsyncis the default setting.O_DSYNC:InnoDBusesO_SYNCto open and flush the log files, andfsync()to flush the data files.InnoDBdoes not useO_DSYNCdirectly because there have been problems with it on many varieties of Unix.littlesync: This option is used for internal performance testing and is currently unsupported. Use at your own risk.nosync: This option is used for internal performance testing and is currently unsupported. Use at your own risk.O_DIRECT:InnoDBusesO_DIRECT(ordirectio()on Solaris) to open the data files, and usesfsync()to flush both the data and log files. This option is available on some GNU/Linux versions, FreeBSD, and Solaris.
The
innodb_flush_methodoptions for Windows systems include:async_unbuffered:InnoDBuses Windows asynchronous I/O and non-buffered I/O.async_unbufferedis the default setting on Windows systems.normal:InnoDBuses a simulated asynchronous I/O and buffered I/O. This option is used for internal performance testing and is currently unsupported. Use at your own risk.unbuffered:InnoDBuses a simulated asynchronous I/O and non-buffered I/O. This option is used for internal performance testing and is currently unsupported. Use at your own risk.
How each settings affects performance depends on hardware configuration and workload. Benchmark your particular configuration to decide which setting to use, or whether to keep the default setting. Examine the
Innodb_data_fsyncsstatus variable to see the overall number offsync()calls for each setting. The mix of read and write operations in your workload can affect how a setting performs. For example, on a system with a hardware RAID controller and battery-backed write cache,O_DIRECTcan help to avoid double buffering between theInnoDBbuffer pool and the operating system's file system cache. On some systems whereInnoDBdata and log files are located on a SAN, the default value orO_DSYNCmight be faster for a read-heavy workload with mostlySELECTstatements. Always test this parameter with hardware and workload that reflect your production environment. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.Prior to MySQL 5.1.24, the default
innodb_flush_methodoption was namedfdatasync. Whenfdatasyncwasspecified,InnoDBused thefsync()system call to flush both the data and log files. To avoid confusing thefdatasyncoption name with thefdatasync()system call, the option name was changed tofsyncin MySQL 5.1.24. -
Introduced 5.5.18 Command-Line Format --innodb_force_load_corruptedSystem Variable Name innodb_force_load_corruptedVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default OFFLets 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=#System Variable Name innodb_force_recoveryVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 0Min Value 0Max Value 6The crash recovery mode, typically only changed in serious troubleshooting situations. Possible values are from 0 to 6. For the meanings of these values and important information about
innodb_force_recovery, see Section 14.23.2, “Forcing InnoDB Recovery”. -
Command-Line Format --innodb_io_capacity=#System Variable Name innodb_io_capacityVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integer Default 200Min Value 100Max Value 2**32-1Permitted Values (64-bit platforms) Type integer Default 200Min Value 100Max Value 2**64-1The
innodb_io_capacityparameter sets an upper limit on I/O activity performed byInnoDBbackground tasks, such as flushing pages from the buffer pool and merging data from the change buffer.The
innodb_io_capacitylimit is a total limit for all buffer pool instances. When dirty pages are flushed, the limit is divided equally among buffer pool instances.innodb_io_capacityshould be set to approximately the number of I/O operations that the system can perform per second. Ideally, keep the setting as low as practical, but not so low that background activities fall behind. If the value is too high, data is removed from the buffer pool and insert buffer too quickly for caching to provide a significant benefit.The default value is 200. For busy systems capable of higher I/O rates, you can set a higher value to help the server handle the background maintenance work associated with a high rate of row changes.
In general, you can increase the value as a function of the number of drives used for
InnoDBI/O. For example, you can increase the value on systems that use multiple disks or solid-state disks (SSD).The default setting of 200 is generally sufficient for a lower-end SSD. For a higher-end, bus-attached SSD, consider a higher setting such as 1000, for example. For systems with individual 5400 RPM or 7200 RPM drives, you might lower the value to the former default of
100, which represents an estimated proportion of the I/O operations per second (IOPS) available to older-generation disk drives that could perform about 100 IOPS.Although you can specify a very high value such as one million, in practice such large values have little if any benefit. Generally, a value of 20000 or higher is not recommended unless you have proven that lower values are insufficient for your workload.
Consider write workload when tuning
innodb_io_capacity. Systems with large write workloads are likely to benefit from a higher setting. A lower setting may be sufficient for systems with a small write workload.You can set
innodb_io_capacityin the MySQL option file (my.cnformy.ini) or change it dynamically using aSET GLOBALstatement, which requires theSUPERprivilege.See Section 14.9.7, “Configuring the InnoDB Master Thread I/O Rate” for more guidelines about this option. For general information about
InnoDBI/O performance, see Section 8.5.7, “Optimizing InnoDB Disk I/O”. -
Introduced 5.5.14 Command-Line Format --innodb_large_prefixSystem Variable Name innodb_large_prefixVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default OFFEnable this option to allow index key prefixes longer than 767 bytes (up to 3072 bytes), for
InnoDBtables that use theDYNAMICandCOMPRESSEDrow formats. (Creating such tables also requires the option valuesinnodb_file_format=barracudaandinnodb_file_per_table=true.) See Section 14.11.8, “Limits on InnoDB Tables” for the relevant maximums associated with index key prefixes under various settings.For tables using the
REDUNDANTandCOMPACTrow 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 aREDUNDANTorCOMPACTtable causes anER_INDEX_COLUMN_TOO_LONGerror. innodb_limit_optimistic_insert_debugCommand-Line Format --innodb_limit_optimistic_insert_debug=#System Variable Name innodb_limit_optimistic_insert_debugVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Min Value 0Max Value 2**32-1Limits the number of records per B-tree page. A default value of 0 means that no limit is imposed. This option is only available if debugging support is compiled in using the
WITH_DEBUGCMake option.-
Command-Line Format --innodb_lock_wait_timeout=#System Variable Name innodb_lock_wait_timeoutVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integer Default 50Min Value 1Max Value 1073741824The length of time in seconds an
InnoDBtransaction 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 anotherInnoDBtransaction 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_timeoutoption. See also Section 14.23.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_timeoutapplies toInnoDBrow locks only. A MySQL table lock does not happen insideInnoDBand this timeout does not apply to waits for table locks.The lock wait timeout value does not apply to deadlocks, because
InnoDBdetects them immediately and rolls back one of the deadlocked transactions.As of MySQL 5.5,
innodb_lock_wait_timeoutcan be set at runtime with theSET GLOBALorSET SESSIONstatement. Changing theGLOBALsetting requires theSUPERprivilege and affects the operation of all clients that subsequently connect. Any client can change theSESSIONsetting forinnodb_lock_wait_timeout, which affects only that client. innodb_locks_unsafe_for_binlogCommand-Line Format --innodb_locks_unsafe_for_binlogSystem Variable Name innodb_locks_unsafe_for_binlogVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default OFFThis variable affects how
InnoDBuses gap locking for searches and index scans. Normally,InnoDBuses an algorithm called next-key locking that combines index-row locking with gap locking.InnoDBperforms 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 recordRin an index, another session cannot insert a new index record in the gap immediately beforeRin the index order. See Section 14.8.1, “InnoDB Locking”.By default, the value of
innodb_locks_unsafe_for_binlogis 0 (disabled), which means that gap locking is enabled:InnoDBuses next-key locks for searches and index scans. To enable the variable, set it to 1. This causes gap locking to be disabled:InnoDBuses only index-record locks for searches and index scans.Enabling
innodb_locks_unsafe_for_binlogdoes not disable the use of gap locking for foreign-key constraint checking or duplicate-key checking.The effects of enabling
innodb_locks_unsafe_for_binlogare the same as setting the transaction isolation level toREAD COMMITTED, with these exceptions:Enabling
innodb_locks_unsafe_for_binlogis 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_binlogcan be set only at server startup, whereas the isolation level can be set at startup or changed at runtime.
READ COMMITTEDtherefore offers finer and more flexible control thaninnodb_locks_unsafe_for_binlog. For additional details about the effect of isolation level on gap locking, see Section 14.8.2.1, “Transaction Isolation Levels”.Enabling
innodb_locks_unsafe_for_binlogmay 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 theidcolumn of thechildtable 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
idis 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 sameSELECTagain 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,InnoDBdoes not guarantee serializability. Therefore, ifinnodb_locks_unsafe_for_binlogis enabled,InnoDBguarantees at most an isolation level ofREAD COMMITTED. (Conflict serializability is still guaranteed.) For additional information about phantoms, see Section 14.8.4, “Phantom Rows”.Enabling
innodb_locks_unsafe_for_binloghas additional effects:For
UPDATEorDELETEstatements,InnoDBholds locks only for rows that it updates or deletes. Record locks for nonmatching rows are released after MySQL has evaluated theWHEREcondition. This greatly reduces the probability of deadlocks, but they can still happen.For
UPDATEstatements, if a row is already locked,InnoDBperforms a “semi-consistent” read, returning the latest committed version to MySQL so that MySQL can determine whether the row matches theWHEREcondition of theUPDATE. If the row matches (must be updated), MySQL reads the row again and this timeInnoDBeither 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.11.9, “Clustered and Secondary Indexes”).
Suppose that one client performs an
UPDATEusing these statements:SET autocommit = 0; UPDATE t SET b = 5 WHERE b = 3;
Suppose also that a second client performs an
UPDATEby executing these statements following those of the first client:SET autocommit = 0; UPDATE t SET b = 4 WHERE b = 2;
As
InnoDBexecutes eachUPDATE, it first acquires an exclusive lock for each row, and then determines whether to modify it. IfInnoDBdoes not modify the row andinnodb_locks_unsafe_for_binlogis enabled, it releases the lock. Otherwise,InnoDBretains the lock until the end of the transaction. This affects transaction processing as follows.If
innodb_locks_unsafe_for_binlogis disabled, the firstUPDATEacquires 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
UPDATEblocks as soon as it tries to acquire any locks (because first update has retained locks on all rows), and does not proceed until the firstUPDATEcommits or rolls back:x-lock(1,2); block and wait for first UPDATE to commit or roll back
If
innodb_locks_unsafe_for_binlogis enabled, the firstUPDATEacquires 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,InnoDBdoes a “semi-consistent” read, returning the latest committed version of each row to MySQL so that MySQL can determine whether the row matches theWHEREcondition of theUPDATE: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=#System Variable Name innodb_log_buffer_sizeVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 8388608Min Value 262144Max Value 4294967295The size in bytes of the buffer that
InnoDBuses 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 transactions that update, insert, or delete many rows, making the log buffer larger saves disk I/O. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”. -
Command-Line Format --innodb_log_file_size=#System Variable Name innodb_log_file_sizeVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 5242880Min Value 1048576Max Value 4GB / innodb_log_files_in_groupThe size in bytes of each log file in a log group. The combined size of log files (
innodb_log_file_size*innodb_log_files_in_group) cannot exceed a maximum value that is slightly less than 4GB. 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.Generally, the combined size of the log files should be large enough that the server can smooth out peaks and troughs in workload activity, which often means that there is enough redo log space to handle more than an hour of write activity. The larger the value, the less checkpoint flush activity is needed in the buffer pool, saving disk I/O. Larger log files also make crash recovery slower, although improvements to recovery performance in MySQL 5.5 and higher make the log file size less of a consideration. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.
-
Command-Line Format --innodb_log_files_in_group=#System Variable Name innodb_log_files_in_groupVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 2Min Value 2Max Value 100The number of log files in the log group.
InnoDBwrites to the files in a circular fashion. The default (and recommended) value is 2. The location of these files is specified byinnodb_log_group_home_dir. -
Command-Line Format --innodb_log_group_home_dir=dir_nameSystem Variable Name innodb_log_group_home_dirVariable Scope Global Dynamic Variable No Permitted Values Type directory name The directory path to the
InnoDBredo log files, whose number is specified byinnodb_log_files_in_group. If you do not specify anyInnoDBlog variables, the default is to create two files namedib_logfile0andib_logfile1in the MySQL data directory. Their size is given by the size of theinnodb_log_file_sizesystem variable. -
Command-Line Format --innodb_max_dirty_pages_pct=#System Variable Name innodb_max_dirty_pages_pctVariable Scope Global Dynamic Variable Yes Permitted Values Type numeric Default 75Min Value 0Max Value 99InnoDBtries to flush data from the buffer pool so that the percentage of dirty pages does not exceed this value. Specify an integer in the range from 0 to 99. The default value is 75.For additional information about this variable, see Section 14.9.2.5, “Configuring InnoDB Buffer Pool Flushing”. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.
-
Command-Line Format --innodb_max_purge_lag=#System Variable Name innodb_max_purge_lagVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Min Value 0Max Value 4294967295This variable controls how to delay
INSERT,UPDATE, andDELETEoperations when purge operations are lagging (see Section 14.6, “InnoDB Multi-Versioning”). The default value is 0 (no delays).The
InnoDBtransaction system maintains a list of transactions that have index records delete-marked byUPDATEorDELETEoperations. The length of this list represents thepurge_lagvalue. Whenpurge_lagexceedsinnodb_max_purge_lag, eachINSERT,UPDATE, andDELETEoperation 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
InnoDBtable rows.The lag value is displayed as the history list length in the
TRANSACTIONSsection 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
For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.
Has no effect.
-
Command-Line Format --innodb_old_blocks_pct=#System Variable Name innodb_old_blocks_pctVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 37Min Value 5Max Value 95Specifies the approximate percentage of the
InnoDBbuffer 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.9.2.3, “Making the Buffer Pool Scan Resistant” for more information. See Section 14.9.2.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=#System Variable Name innodb_old_blocks_timeVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Min Value 0Max Value 2**32-1Non-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.9.2.3, “Making the Buffer Pool Scan Resistant” for more information. See Section 14.9.2.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=#System Variable Name innodb_open_filesVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 300Min Value 10Max Value 4294967295This variable is relevant only if you use multiple
InnoDBtablespaces. It specifies the maximum number of.ibdfiles that MySQL can keep open at one time. The minimum value is 10. The default value is 300.The file descriptors used for
.ibdfiles are forInnoDBtables only. They are independent of those specified by the--open-files-limitserver option, and do not affect the operation of the table cache. -
Introduced 5.5.30 Command-Line Format --innodb_print_all_deadlocks=#System Variable Name innodb_print_all_deadlocksVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default OFFWhen this option is enabled, information about all deadlocks in
InnoDBuser transactions is recorded in themysqlderror log. Otherwise, you see information about only the last deadlock, using theSHOW ENGINE INNODB STATUScommand. An occasionalInnoDBdeadlock is not necessarily an issue, becauseInnoDBdetects 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 orSELECT ... FOR UPDATEstatements 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=#System Variable Name innodb_purge_batch_sizeVariable Scope Global Dynamic Variable Yes Permitted Values (>= 5.5.4) Type integer Default 20Min Value 1Max Value 5000Defines the number of undo log pages that purge parses and processes in one batch from the history list. The
innodb_purge_batch_sizeoption also defines the number of undo log pages that purge frees after every 128 iterations through the undo logs.The
innodb_purge_batch_sizeoption is intended for advanced performance tuning in combination with theinnodb_purge_threadssetting. Most MySQL users need not changeinnodb_purge_batch_sizefrom its default value. -
Introduced 5.5.4 Command-Line Format --innodb_purge_threads=#System Variable Name innodb_purge_threadsVariable Scope Global Dynamic Variable No Permitted Values (>= 5.5.4) Type integer Default 0Min Value 0Max Value 1The number of background threads devoted to the
InnoDBpurge 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 withinInnoDB, 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=#System Variable Name innodb_random_read_aheadVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default OFFEnables the random read-ahead technique for optimizing
InnoDBI/O. Random read-ahead functionality was removed from theInnoDB Plugin(version 1.0.4) and was therefore not included in MySQL 5.5.0 whenInnoDB Pluginbecame the “built-in” version ofInnoDB. Random read-ahead was reintroduced in MySQL 5.1.59 and 5.5.16 and higher along with theinnodb_random_read_aheadconfiguration option, which is disabled by default.See Section 14.9.2.4, “Configuring InnoDB Buffer Pool Prefetching (Read-Ahead)” 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=#System Variable Name innodb_read_ahead_thresholdVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 56Min Value 0Max Value 64Controls the sensitivity of linear read-ahead that
InnoDBuses to prefetch pages into the buffer pool. IfInnoDBreads at leastinnodb_read_ahead_thresholdpages 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:InnoDBmust read at least 56 pages sequentially from an extent to initiate an asynchronous read for the following extent.Knowing how many pages are read through this read-ahead mechanism, and how many of them are evicted from the buffer pool without ever being accessed, can be useful to help fine-tune the
innodb_read_ahead_thresholdparameter. As of MySQL 5.5,SHOW ENGINE INNODB STATUSoutput displays counter information from theInnodb_buffer_pool_read_aheadandInnodb_buffer_pool_read_ahead_evictedglobal status variables. These variables indicate the number of pages brought into the buffer pool by read-ahead requests, and the number of such pages evicted from the buffer pool without ever being accessed respectively. These counters provide global values since the last server restart.SHOW ENGINE INNODB STATUSalso shows the rate at which the read-ahead pages are read in and the rate at which such pages are evicted without being accessed. The per-second averages are based on the statistics collected since the last invocation ofSHOW ENGINE INNODB STATUSand are displayed in theBUFFER POOL AND MEMORYsection of the output.See Section 14.9.2.4, “Configuring InnoDB Buffer Pool Prefetching (Read-Ahead)” for more information. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.
-
Command-Line Format --innodb_read_io_threads=#System Variable Name innodb_read_io_threadsVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 4Min Value 1Max Value 64The number of I/O threads for read operations in
InnoDB. The default value is 4. Its counterpart for write threads isinnodb_write_io_threads. See Section 14.9.6, “Configuring the Number of Background InnoDB I/O Threads” for more information. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.NoteOn Linux systems, running multiple MySQL servers (typically more than 12) with default settings for
innodb_read_io_threads,innodb_write_io_threads, and the Linuxaio-max-nrsetting can exceed system limits. Ideally, increase theaio-max-nrsetting; as a workaround, you might reduce the settings for one or both of the MySQL configuration options. -
Command-Line Format --innodb_replication_delay=#System Variable Name innodb_replication_delayVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Min Value 0Max Value 4294967295The replication thread delay (in ms) on a slave server if
innodb_thread_concurrencyis reached. -
Command-Line Format --innodb_rollback_on_timeoutSystem Variable Name innodb_rollback_on_timeoutVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default OFFIn MySQL 5.5,
InnoDBrolls back only the last statement on a transaction timeout by default. If--innodb_rollback_on_timeoutis specified, a transaction timeout causesInnoDBto 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=#System Variable Name innodb_rollback_segmentsVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 128Min Value 1Max Value 128Defines how many of the rollback segments in the system tablespace are used for InnoDB transactions. 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=#System Variable Name innodb_spin_wait_delayVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integer Default 6Min Value 0Max Value 2**32-1Permitted Values (64-bit platforms) Type integer Default 6Min Value 0Max Value 2**64-1The 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.9.8, “Configuring Spin Lock Polling” for more information.
-
Introduced 5.5.10 Command-Line Format --innodb_stats_method=nameSystem Variable Name innodb_stats_methodVariable Scope Global Dynamic Variable Yes Permitted Values Type enumeration Default nulls_equalValid Values nulls_equalnulls_unequalnulls_ignoredHow the server treats
NULLvalues when collecting statistics about the distribution of index values forInnoDBtables. This variable has three possible values,nulls_equal,nulls_unequal, andnulls_ignored. Fornulls_equal, allNULLindex values are considered equal and form a single value group that has a size equal to the number ofNULLvalues. Fornulls_unequal,NULLvalues are considered unequal, and eachNULLforms a distinct value group of size 1. Fornulls_ignored,NULLvalues 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_metadataSystem Variable Name innodb_stats_on_metadataVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default ONWhen this variable is enabled (which is the default, as before the variable was created),
InnoDBupdates statistics when metadata statements such asSHOW TABLE STATUSorSHOW INDEXare run, or when accessing theINFORMATION_SCHEMA.TABLESorINFORMATION_SCHEMA.STATISTICStables. (These updates are similar to what happens forANALYZE TABLE.) When disabled,InnoDBdoes 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 involveInnoDBtables.To change the setting, issue the statement
SET GLOBAL innodb_stats_on_metadata=, wheremodeis eithermodeONorOFF(or1or0). Changing this setting requires theSUPERprivilege and immediately affects the operation of all connections. -
Command-Line Format --innodb_stats_sample_pages=#System Variable Name innodb_stats_sample_pagesVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 8Min Value 1Max Value 2**64-1The number of index pages to sample for index distribution statistics such as are calculated by
ANALYZE TABLE. The default value is 8. For additional information, see Section 14.9.10, “Configuring Optimizer Statistics for InnoDB”.Setting a high value for
innodb_stats_sample_pagescould result in lengthyANALYZE TABLEexecution time. To estimate the number of database pages accessed byANALYZE TABLE, see Section 14.9.10.1, “Estimating ANALYZE TABLE Complexity for InnoDB Tables”. -
Command-Line Format --innodb_strict_mode=#System Variable Name innodb_strict_modeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type boolean Default OFFWhen
innodb_strict_modeisON,InnoDBreturns errors rather than warnings for certain conditions. The default value isOFF.Strict mode helps guard against ignored typos and syntax errors in SQL, or other unintended consequences of various combinations of operational modes and SQL statements. When
innodb_strict_modeisON,InnoDBraises error conditions in certain cases, rather than issuing a warning and processing the specified statement (perhaps with unintended behavior). This is analogous tosql_modein MySQL, which controls what SQL syntax MySQL accepts, and determines whether it silently ignores errors, or validates input syntax and data values.The
innodb_strict_modesetting affects the handling of syntax errors forCREATE TABLE,ALTER TABLEandCREATE INDEXstatements.innodb_strict_modealso enables a record size check, so that anINSERTorUPDATEnever fails due to the record being too large for the selected page size.Oracle recommends enabling
innodb_strict_modewhen usingROW_FORMATandKEY_BLOCK_SIZEclauses onCREATE TABLE,ALTER TABLE, andCREATE INDEXstatements. Wheninnodb_strict_modeisOFF,InnoDBignores conflicting clauses and creates the table or index, with only a warning in the message log. The resulting table might have different behavior than you intended, such as having no compression when you tried to create a compressed table. Wheninnodb_strict_modeisON, such problems generate an immediate error and the table or index is not created, avoiding a troubleshooting session later.You can turn
innodb_strict_modeONorOFFon the command line when you startmysqld, or in the configuration filemy.cnformy.ini. You can also enable or disableinnodb_strict_modeat runtime with the statementSET [GLOBAL|SESSION] innodb_strict_mode=, wheremodeis eithermodeONorOFF. Changing theGLOBALsetting requires theSUPERprivilege and affects the operation of all clients that subsequently connect. Any client can change theSESSIONsetting forinnodb_strict_mode, and the setting affects only that client. -
Command-Line Format --innodb_support_xaSystem Variable Name innodb_support_xaVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type boolean Default TRUEEnables
InnoDBsupport 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
InnoDBtables. 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=#System Variable Name innodb_sync_spin_loopsVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 30Min Value 0Max Value 4294967295The number of times a thread waits for an
InnoDBmutex to be freed before the thread is suspended. The default value is 30. -
Command-Line Format --innodb_table_locksSystem Variable Name innodb_table_locksVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type boolean Default TRUEIf
autocommit = 0,InnoDBhonorsLOCK TABLES; MySQL does not return fromLOCK TABLES ... WRITEuntil all other threads have released all their locks to the table. The default value ofinnodb_table_locksis 1, which means thatLOCK TABLEScauses InnoDB to lock a table internally ifautocommit = 0.As of MySQL 5.5.3,
innodb_table_locks = 0has no effect for tables locked explicitly withLOCK TABLES ... WRITE. It still has an effect for tables locked for read or write byLOCK TABLES ... WRITEimplicitly (for example, through triggers) or byLOCK TABLES ... READ. -
Command-Line Format --innodb_thread_concurrency=#System Variable Name innodb_thread_concurrencyVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Min Value 0Max Value 1000InnoDBtries to keep the number of operating system threads concurrently insideInnoDBless than or equal to the limit given by this variable (InnoDBuses operating system threads to process user transactions). Once the number of threads reaches this limit, additional threads are placed into a wait state within a “First In, First Out” (FIFO) queue for execution. Threads waiting for locks are not counted in the number of concurrently executing threads.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
InnoDBto create as many threads as it needs. A value of 0 also disables thequeries inside InnoDBandqueries in queue countersin theROW OPERATIONSsection ofSHOW ENGINE INNODB STATUSoutput.Consider setting this variable if your MySQL instance shares CPU resources with other applications, or if your workload or number of concurrent users is growing. The correct setting depends on workload, computing environment, and the version of MySQL that you are running. You will need to test a range of values to determine the setting that provides the best performance.
innodb_thread_concurrencyis a dynamic variable, which allows you to experiment with different settings on a live test system. If a particular setting performs poorly, you can quickly setinnodb_thread_concurrencyback to 0.Use the following guidelines to help find and maintain an appropriate setting:
If the number of concurrent user threads for a workload is less than 64, set
innodb_thread_concurrency=0.If your workload is consistently heavy or occasionally spikes, start by setting
innodb_thread_concurrency=128, and lowering the value to 96, 80, 64, and so on, until you find the number of threads that provides the best performance. For example, suppose your system typically has 40 to 50 users, but periodically the number increases to 60, 70, or even 200. You find that performance is stable at 80 concurrent users but starts to show a regression above this number. In this case, you would setinnodb_thread_concurrency=80to avoid impacting performance.If you do not want
InnoDBto use more than a certain number of vCPUs for user threads (20 vCPUs for example), setinnodb_thread_concurrencyto this number (or possibly lower, depending on performance results). If your goal is to isolate MySQL from other applications, you may consider binding themysqldprocess exclusively to the vCPUs. Be aware, however, that exclusive binding could result in non-optimal hardware usage if themysqldprocess is not consistently busy. In this case, you might bind themysqldprocess to the vCPUs but also allow other applications to use some or all of the vCPUs.NoteFrom an operating system perspective, using a resource management solution (if available) to manage how CPU time is shared among applications may be preferable to binding the
mysqldprocess. For example, you could assign 90% of vCPU time to a given application while other critical process are not running, and scale that value back to 40% when other critical processes are running.innodb_thread_concurrencyvalues that are too high can cause performance regression due to increased contention on system internals and resources.In some cases, the optimal
innodb_thread_concurrencysetting can be smaller than the number of vCPUs.Monitor and analyze your system regularly. Changes to workload, number of users, or computing environment may require that you adjust the
innodb_thread_concurrencysetting.
For related information, see Section 14.9.5, “Configuring Thread Concurrency for InnoDB”.
-
Command-Line Format --innodb_thread_sleep_delay=#System Variable Name innodb_thread_sleep_delayVariable Scope Global Dynamic Variable Yes Permitted Values (>= 5.5.37) Type integer Default 10000Min Value 0Max Value 1000000Permitted Values (32-bit platforms, <= 5.5.36) Type integer Default 10000Min Value 0Max Value 4294967295Permitted Values (64-bit platforms, <= 5.5.36) Type integer Default 10000Min Value 0Max Value 18446744073709551615How long
InnoDBthreads sleep before joining theInnoDBqueue, in microseconds. The default value is 10000. A value of 0 disables sleep.For more information, see Section 14.9.5, “Configuring Thread Concurrency for InnoDB”.
-
Introduced 5.5.4 Command-Line Format --innodb_use_native_aio=#System Variable Name innodb_use_native_aioVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default ONSpecifies 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.
As of MySQL 5.5, the asynchronous I/O capability that
InnoDBhas on Windows systems is available on Linux systems. (Other Unix-like systems continue to use synchronous I/O calls.) This feature improves the scalability of heavily I/O-bound systems, which typically show many pending reads/writes in the output of the commandSHOW ENGINE INNODB STATUS\G.Running with a large number of
InnoDBI/O threads, and especially running multiple such instances on the same server machine, can exceed capacity limits on Linux systems. In this case, you may receive the following error:EAGAIN: The specified maxevents exceeds the user's limit of available events.
You can typically address this error by writing a higher limit to
/proc/sys/fs/aio-max-nr.However, if a problem with the asynchronous I/O subsystem in the OS prevents
InnoDBfrom starting, you can start the server withinnodb_use_native_aio=0disabled (useinnodb_use_native_aio=0in the option file). This option may also be turned off automatically during startup ifInnoDBdetects a potential problem such as a combination oftmpdirlocation,tmpfsfilesystem, and Linux kernel that does not support AIO ontmpfs.This variable was added in MySQL 5.5.4.
innodb_trx_purge_view_update_only_debugCommand-Line Format --innodb_trx_purge_view_update_only_debug=#System Variable Name innodb_trx_purge_view_update_only_debugVariable Scope Global Dynamic Variable Yes Permitted Values Type boolean Default OFFPauses purging of delete-marked records while allowing the purge view to be updated. This option artificially creates a situation in which the purge view is updated but purges have not yet been performed. This option is only available if debugging support is compiled in using the
WITH_DEBUGCMake option.-
Command-Line Format --innodb_trx_rseg_n_slots_debug=#System Variable Name innodb_trx_rseg_n_slots_debugVariable Scope Global Dynamic Variable Yes Permitted Values Type integer Default 0Max Value 1024Sets a debug flag that limits
TRX_RSEG_N_SLOTSto a given value for thetrx_rsegf_undo_find_freefunction which looks for a free slot for an undo log segment. This option is only available if debugging support is compiled in using theWITH_DEBUGCMake option. -
Command-Line Format --innodb_use_sys_malloc=#System Variable Name innodb_use_sys_mallocVariable Scope Global Dynamic Variable No Permitted Values Type boolean Default ONWhether
InnoDBuses the operating system memory allocator (ON) or its own (OFF). The default value isON. See Section 14.9.3, “Configuring the Memory Allocator for InnoDB” for more information. The
InnoDBversion number. Starting in 5.5.30, the separate numbering forInnoDBis discontinued and this value is the same as for theversionvariable.-
Command-Line Format --innodb_write_io_threads=#System Variable Name innodb_write_io_threadsVariable Scope Global Dynamic Variable No Permitted Values Type integer Default 4Min Value 1Max Value 64The number of I/O threads for write operations in
InnoDB. The default value is 4. Its counterpart for read threads isinnodb_read_io_threads. See Section 14.9.6, “Configuring the Number of Background InnoDB I/O Threads” for more information. For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.NoteOn Linux systems, running multiple MySQL servers (typically more than 12) with default settings for
innodb_read_io_threads,innodb_write_io_threads, and the Linuxaio-max-nrsetting can exceed system limits. Ideally, increase theaio-max-nrsetting; as a workaround, you might reduce the settings for one or both of the MySQL configuration options.
You should also take into consideration the value of
sync_binlog, which controls
synchronization of the binary log to disk.
For general I/O tuning advice, see Section 8.5.7, “Optimizing InnoDB Disk I/O”.
* This limit varies in different kernels.
http://krow.livejournal.com/542306.html
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).
[*] 2009/10 Initialising a 10 GB buffer pool takes 6 seconds, larger configurations may take proportionally longer.
http://www.tocker.ca/2013/09/17/what-to-tune-in-mysql-56-after-installation.html