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=valuevar_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.4. InnoDB Option/Variable
      Reference
| Name | Cmd-Line | Option file | System Var | Status Var | Var Scope | Dynamic | 
|---|---|---|---|---|---|---|
| Com_show_innodb_status | Yes | Both | No | |||
| Com_show_ndb_status | Yes | Both | No | |||
| foreign_key_checks | Yes | Session | Yes | |||
| have_innodb | Yes | Global | No | |||
| innodb | Yes | Yes | ||||
| innodb_adaptive_hash_index | Yes | Yes | Yes | Global | No | |
| innodb_additional_mem_pool_size | Yes | Yes | Yes | Global | No | |
| innodb_autoextend_increment | Yes | Yes | Yes | Global | Yes | |
| innodb_autoinc_lock_mode | Yes | Yes | Yes | Global | No | |
| innodb_buffer_pool_awe_mem_mb | Yes | Yes | Yes | Global | No | |
| Innodb_buffer_pool_pages_data | Yes | Global | No | |||
| Innodb_buffer_pool_pages_dirty | Yes | Global | No | |||
| Innodb_buffer_pool_pages_flushed | Yes | Global | No | |||
| Innodb_buffer_pool_pages_free | Yes | Global | No | |||
| Innodb_buffer_pool_pages_latched | Yes | Global | No | |||
| Innodb_buffer_pool_pages_misc | Yes | Global | No | |||
| Innodb_buffer_pool_pages_total | Yes | Global | No | |||
| Innodb_buffer_pool_read_ahead_rnd | Yes | Global | No | |||
| Innodb_buffer_pool_read_ahead_seq | Yes | Global | No | |||
| Innodb_buffer_pool_read_requests | Yes | Global | No | |||
| Innodb_buffer_pool_reads | Yes | Global | No | |||
| innodb_buffer_pool_size | Yes | Yes | Yes | Global | No | |
| Innodb_buffer_pool_wait_free | Yes | Global | No | |||
| Innodb_buffer_pool_write_requests | Yes | Global | No | |||
| innodb_checksums | Yes | Yes | Yes | Global | No | |
| innodb_commit_concurrency | Yes | Yes | Yes | Global | Yes | |
| innodb_concurrency_tickets | Yes | Yes | Yes | Global | Yes | |
| innodb_data_file_path | Yes | Yes | Yes | Global | No | |
| Innodb_data_fsyncs | Yes | Global | No | |||
| innodb_data_home_dir | Yes | Yes | Yes | Global | No | |
| Innodb_data_pending_fsyncs | Yes | Global | No | |||
| Innodb_data_pending_reads | Yes | Global | No | |||
| Innodb_data_pending_writes | Yes | Global | No | |||
| Innodb_data_read | Yes | Global | No | |||
| Innodb_data_reads | Yes | Global | No | |||
| Innodb_data_writes | Yes | Global | No | |||
| Innodb_data_written | Yes | Global | No | |||
| Innodb_dblwr_pages_written | Yes | Global | No | |||
| Innodb_dblwr_writes | Yes | Global | No | |||
| innodb_doublewrite | Yes | Yes | Yes | Global | No | |
| innodb_fast_shutdown | Yes | Yes | Yes | Global | Yes | |
| innodb_file_io_threads | Yes | Yes | Yes | Global | No | |
| innodb_file_per_table | Yes | Yes | Yes | Global | No | |
| innodb_flush_log_at_trx_commit | Yes | Yes | Yes | Global | Yes | |
| innodb_flush_method | Yes | Yes | Yes | Global | No | |
| innodb_force_recovery | Yes | Yes | Yes | Global | No | |
| innodb_lock_wait_timeout | Yes | Yes | Yes | Global | No | |
| innodb_locks_unsafe_for_binlog | Yes | Yes | Yes | Global | No | |
| innodb_log_arch_dir | Yes | Yes | Yes | Global | No | |
| innodb_log_archive | Yes | Yes | Yes | Global | No | |
| innodb_log_buffer_size | Yes | Yes | Yes | Global | No | |
| innodb_log_file_size | Yes | Yes | Yes | Global | No | |
| innodb_log_files_in_group | Yes | Yes | Yes | Global | No | |
| innodb_log_group_home_dir | Yes | Yes | Yes | Global | No | |
| Innodb_log_waits | Yes | Global | No | |||
| Innodb_log_write_requests | Yes | Global | No | |||
| Innodb_log_writes | Yes | Global | No | |||
| innodb_max_dirty_pages_pct | Yes | Yes | Yes | Global | Yes | |
| innodb_max_purge_lag | Yes | Yes | Yes | Global | Yes | |
| innodb_mirrored_log_groups | Yes | Yes | Yes | Global | No | |
| innodb_open_files | Yes | Yes | Yes | Global | No | |
| Innodb_os_log_fsyncs | Yes | Global | No | |||
| Innodb_os_log_pending_fsyncs | Yes | Global | No | |||
| Innodb_os_log_pending_writes | Yes | Global | No | |||
| Innodb_os_log_written | Yes | Global | No | |||
| Innodb_page_size | Yes | Global | No | |||
| Innodb_pages_created | Yes | Global | No | |||
| Innodb_pages_read | Yes | Global | No | |||
| Innodb_pages_written | Yes | Global | No | |||
| innodb_rollback_on_timeout | Yes | Yes | Yes | Global | No | |
| Innodb_row_lock_current_waits | Yes | Global | No | |||
| Innodb_row_lock_time | Yes | Global | No | |||
| Innodb_row_lock_time_avg | Yes | Global | No | |||
| Innodb_row_lock_time_max | Yes | Global | No | |||
| Innodb_row_lock_waits | Yes | Global | No | |||
| Innodb_rows_deleted | Yes | Global | No | |||
| Innodb_rows_inserted | Yes | Global | No | |||
| Innodb_rows_read | Yes | Global | No | |||
| Innodb_rows_updated | Yes | Global | No | |||
| innodb_stats_on_metadata | Yes | Yes | Yes | Global | Yes | |
| innodb_status_file | Yes | Yes | ||||
| innodb_support_xa | Yes | Yes | Yes | Both | Yes | |
| innodb_sync_spin_loops | Yes | Yes | Yes | Global | Yes | |
| innodb_table_locks | Yes | Yes | Yes | Both | Yes | |
| innodb_thread_concurrency | Yes | Yes | Yes | Global | Yes | |
| innodb_thread_sleep_delay | Yes | Yes | Yes | Global | Yes | |
| innodb_use_legacy_cardinality_algorithm | Yes | Yes | Yes | Global | Yes | |
| skip-innodb | Yes | Yes | ||||
| skip-innodb-checksums | Yes | Yes | ||||
| timed_mutexes | Yes | Yes | Yes | Global | Yes | |
| unique_checks | Yes | Session | Yes | 
      InnoDB command options:
    
          This option that causes the server to behave as if the
          built-in InnoDB is not present. It causes
          other InnoDB options not to be recognized.
          This option was added in MySQL 5.1.33.
        
          Controls loading of the InnoDB storage
          engine, if the server was compiled with
          InnoDB support. As of MySQL 5.1.36, this
          option has a tristate format, with possible values of
          OFF, ON, or
          FORCE. Before MySQL 5.1.36, this is a
          boolean option. Use --innodb to
          enable or --skip-innodb to
          disable InnoDB. See
          Section 5.1.3, “Server Options for Loading Plugins”.
        
          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.1.33 | ||
| Command Line Format | --ignore-builtin-innodb | ||
| Config File Format | ignore_builtin_innodb | ||
| Option Sets Variable | Yes, ignore_builtin_innodb | ||
| Variable Name | ignore_builtin_innodb | ||
| Variable Scope | Global | ||
| Dynamic Variable | No | ||
| Permitted Values | 
 | 
          Whether the server was started with the
          --ignore-builtin-innodb option,
          which causes the server to behave as if the built-in
          InnoDB is not present. This variable was
          added in MySQL 5.1.33.
        
| Version Introduced | 5.1.24 | ||||
| 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 | 
 | 
          Whether InnoDB adaptive hash indexes are enabled or disabled
          (see Section 13.6.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.1.24.
        
          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 | 
 | 
          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 | 
 | 
The increment size (in MB) for extending the size of an auto-extending tablespace file when it becomes full. The default value is 8.
| Version Removed | 5.1.13 | ||||||
| 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 | 
 | 
          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
          storage/innobase/os/os0proc.c source
          file.
        
          This variable was removed in MySQL 5.1.13. Before that, it 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.
        
| Version Introduced | 5.1.22 | ||||
| Command Line Format | --innodb_autoinc_lock_mode=# | ||||
| Config File Format | innodb_autoinc_lock_mode | ||||
| Option Sets Variable | Yes, innodb_autoinc_lock_mode | ||||
| Variable Name | innodb_autoinc_lock_mode | ||||
| Variable Scope | Global | ||||
| Dynamic Variable | No | ||||
| Permitted Values | 
 | 
          The locking mode to use for generating auto-increment values.
          The allowable values are 0, 1, or 2, for
          “traditional”, “consecutive”, or
          “interleaved” lock mode, respectively.
          Section 13.6.4.3, “AUTO_INCREMENT Handling in InnoDB”, describes
          the characteristics of these modes.
        
          This variable was added in MySQL 5.1.22 with a default of 1
          (“consecutive” lock mode). Before 5.1.22,
          InnoDB uses “traditional” lock
          mode.
        
| 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 | 
 | 
          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.
        
| 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 | 
 | 
          InnoDB can use checksum validation on all
          pages read from the disk to ensure extra fault tolerance
          against broken hardware or data files. This validation is
          enabled by default. However, under some rare circumstances
          (such as when running benchmarks) this extra safety feature is
          unneeded and can be disabled with
          --skip-innodb-checksums.
        
| Command Line Format | --innodb_commit_concurrency=# | ||||||
| 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 | 
 | 
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.
          As of MySQL 5.1.36, the value of
          innodb_commit_concurrency
          cannot be changed at runtime from zero to nonzero or vice
          versa. The value can still be changed from one nonzero value
          to another.
        
| 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 | 
 | 
          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.
        
| 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 | 
 | 
          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.6.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 | 
 | 
          The common part of the directory path for all
          InnoDB data files in the shared tablespace.
          This setting does not affect the location of per-file
          tablespaces when
          innodb_file_per_table is
          enabled. The default value is the MySQL data directory. If you
          specify the value as an empty string, you can use absolute
          file paths in
          innodb_data_file_path.
        
| Command Line Format | --innodb-doublewrite | ||
| Config File Format | innodb_doublewrite | ||
| Option Sets Variable | Yes, innodb_doublewrite | ||
| Variable Name | innodb_doublewrite | ||
| Variable Scope | Global | ||
| Dynamic Variable | No | ||
| Permitted Values | 
 | 
          If this variable is enabled (the default),
          InnoDB stores all data twice, first to the
          doublewrite buffer, and then to the actual data files. This
          variable can be turned off with
          --skip-innodb_doublewrite
          for benchmarks or cases when top performance is needed rather
          than concern for data integrity or possible failures.
        
| Command Line Format | --innodb_fast_shutdown[=#] | ||||||
| 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 | 
 | 
          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. A value of 2 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 | 
 | 
          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.6.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 | 
 | 
          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, use innodb_flush_log_at_trx_commit =
          1 and sync_binlog = 1 in your
          master server my.cnf file.
        
            Many operating systems and some disk hardware fool the
            flush-to-disk operation. They may tell
            mysqld that the flush has taken place,
            even though it has not. Then the durability of transactions
            is not guaranteed even with the setting 1, and in the worst
            case a power outage can even corrupt the
            InnoDB database. Using a battery-backed
            disk cache in the SCSI disk controller or in the disk itself
            speeds up file flushes, and makes the operation safer. You
            can also try using the Unix command
            hdparm to disable the caching of disk
            writes in hardware caches, or use some other command
            specific to the hardware vendor.
          
| Command Line Format | --innodb_flush_method=name | ||||||
| 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 | 
 | ||||||
| Permitted Values | 
 | ||||||
| Permitted Values | 
 | ||||||
| Permitted Values | 
 | 
          By default, InnoDB uses
          fsync() to flush both the data and log
          files. If innodb_flush_method
          option is set to O_DSYNC,
          InnoDB uses O_SYNC to
          open and flush the log files, and fsync()
          to flush the data files. If O_DIRECT is
          specified (available on some GNU/Linux versions, FreeBSD, and
          Solaris), InnoDB uses
          O_DIRECT (or directio()
          on Solaris) to open the data files, and uses
          fsync() to flush both the data and log
          files. Note that InnoDB uses
          fsync() instead of
          fdatasync(), and it does not use
          O_DSYNC by default because there have been
          problems with it on many varieties of Unix. This variable is
          relevant only for Unix. On Windows, the flush method is always
          async_unbuffered and cannot be changed.
        
          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.
        
          Formerly it was possible to specify a value of
          fdatasync to obtain the default behavior.
          This is no longer possible as of MySQL 5.1.24 because it can
          be confusing that a value of fdatasync
          causes use of fsync() rather than
          fdatasync() for flushing.
        
| 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 | 
 | 
          The crash recovery mode. Possible values are from 0 to 6. The
          meanings of these values are described in
          Section 13.6.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 | 
 | 
          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. (To have the entire transaction roll back, start
          the server with the
          --innodb_rollback_on_timeout
          option, available as of MySQL 5.1.15. See also
          Section 13.6.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 | 
 | 
          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.6.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 sesssion.
            
              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.4.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.6.8.5, “Avoiding the Phantom Problem Using Next-Key Locking”.
        
          Enabling
          innodb_locks_unsafe_for_binlog
          has additional effects:
        
              For UPDATE or
              DELETE statements,
              InnoDB holds locks only for rows that
              it updates or deletes. Record locks for nonmatching rows
              are released after MySQL has evaluated the
              WHERE condition. This greatly reduces
              the probability of deadlocks, but they can still happen.
            
              For UPDATE statements, if a
              row is already locked, InnoDB performs
              a “semi-consistent” read, returning the
              latest committed version to MySQL so that MySQL can
              determine whether the row matches the
              WHERE condition of the
              UPDATE. If the row matches
              (must be updated), MySQL reads the row again and this time
              InnoDB either locks it or waits for a
              lock on it.
            
Consider the following example, beginning with this table:
CREATE TABLE t (a INT NOT NULL, b INT) ENGINE = InnoDB; INSERT INTO t VALUES (1,2),(2,3),(3,2),(4,3),(5,2); COMMIT;
In this case, table has no indexes, so searches and index scans use the hidden clustered index for record locking (see Section 13.6.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)
          For the second UPDATE,
          InnoDB does a
          “semi-consistent” read, returning the latest
          committed version of each row to MySQL so that MySQL can
          determine whether the row matches the WHERE
          condition of the UPDATE:
        
x-lock(1,2); update(1,2) to (1,4); retain x-lock x-lock(2,3); unlock(2,3) x-lock(3,2); update(3,2) to (3,4); retain x-lock x-lock(4,3); unlock(4,3) x-lock(5,2); update(5,2) to (5,4); retain x-lock
          Semi-consistent read is available as of MySQL 5.1.5. Before
          5.1.5, 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. Thus, before MySQL 5.1.5, enabling
          innodb_locks_unsafe_for_binlog
          still does not allow operations such as
          UPDATE to overtake other
          similar operations (such as another
          UPDATE) even when they affect
          different rows.
        
This variable is deprecated, and was removed in MySQL 5.1.21.
This variable is deprecated, and was removed in MySQL 5.1.18.
| 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 | 
 | 
          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 | 
 | 
          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 | 
 | 
          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 | 
 | 
          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 | 
 | 
          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 | 
 | 
          This variable controls how to delay
          INSERT,
          UPDATE, and
          DELETE operations when purge
          operations are lagging (see
          Section 13.6.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 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 | 
 | 
          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.1.15 | 
| 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.1, InnoDB rolls
          back only the last statement on a transaction timeout by
          default. If
          --innodb_rollback_on_timeout is
          specified, a transaction timeout causes
          InnoDB to abort and roll back the entire
          transaction (the same behavior as in MySQL 4.1). This variable
          was added in MySQL 5.1.15.
        
| Version Introduced | 5.1.17 | ||||
| Command Line Format | --innodb_stats_on_metadata | ||||
| Config File Format | innodb_stats_on_metadata | ||||
| Option Sets Variable | Yes, innodb_stats_on_metadata | ||||
| Variable Name | innodb_stats_on_metadata | ||||
| Variable Scope | Global | ||||
| Dynamic Variable | Yes | ||||
| Permitted Values | 
 | 
          When this variable is enabled (which is the default, as before
          the variable was created), InnoDB updates
          statistics during metadata statements such as
          SHOW TABLE STATUS or
          SHOW INDEX, or when accessing
          the INFORMATION_SCHEMA tables
          TABLES or
          STATISTICS. (These updates are
          similar to what happens for ANALYZE
          TABLE.) When disabled, InnoDB
          does not updates statistics during these operations. Disabling
          this variable can improve access speed for schemas that have a
          large number of tables or indexes. It can also improve the
          stability of execution plans for queries that involve
          InnoDB tables.
        
This variable was added in MySQL 5.1.17.
| 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 | 
 | 
          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.
        
| 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 | ||||||
| Permitted Values | 
 | 
          The number of times a thread waits for an
          InnoDB mutex to be freed before the thread
          is suspended. The default value is 20.
        
| 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 | 
 | 
          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 | 
 | 
          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.1.12. From 5.1.12 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 is 20 before MySQL 5.1.11, and 8 from 5.1.11 on.
| 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 | 
 | 
          How long InnoDB threads sleep before
          joining the InnoDB queue, in microseconds.
          The default value is 10,000. A value of 0 disables sleep.
        
          innodb_use_legacy_cardinality_algorithm
        
| Version Introduced | 5.1.35 | ||||
| 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 | 
 | 
          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.1.35 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.
        
This variable is not used in 5.4 because the improved algorithm is used by default.
          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.