Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 34.2Mb
PDF (A4) - 34.2Mb
PDF (RPM) - 32.0Mb
HTML Download (TGZ) - 8.1Mb
HTML Download (Zip) - 8.2Mb
HTML Download (RPM) - 7.0Mb
Man Pages (TGZ) - 146.0Kb
Man Pages (Zip) - 206.9Kb
Info (Gzip) - 3.1Mb
Info (Zip) - 3.1Mb


MySQL 8.0 Reference Manual  /  The InnoDB Storage Engine  /  InnoDB Startup Options and System Variables

Pre-General Availability Draft: 2017-12-11

15.13 InnoDB Startup Options and System Variables

Table 15.14 InnoDB Option and Variable Reference

NameCmd-LineOption FileSystem VarStatus VarVar ScopeDynamic
daemon_memcached_enable_binlogYesYesYes GlobalNo
daemon_memcached_engine_lib_nameYesYesYes GlobalNo
daemon_memcached_engine_lib_pathYesYesYes GlobalNo
daemon_memcached_optionYesYesYes GlobalNo
daemon_memcached_r_batch_sizeYesYesYes GlobalNo
daemon_memcached_w_batch_sizeYesYesYes GlobalNo
foreign_key_checks  Yes BothYes
ignore-builtin-innodbYesYes  GlobalNo
- Variable: ignore_builtin_innodb  Yes GlobalNo
innodbYesYes    
innodb_adaptive_flushingYesYesYes GlobalYes
innodb_adaptive_flushing_lwmYesYesYes GlobalYes
innodb_adaptive_hash_indexYesYesYes GlobalYes
innodb_adaptive_hash_index_partsYesYesYes GlobalNo
innodb_adaptive_max_sleep_delayYesYesYes GlobalYes
innodb_api_bk_commit_intervalYesYesYes GlobalYes
innodb_api_disable_rowlockYesYesYes GlobalNo
innodb_api_enable_binlogYesYesYes GlobalNo
innodb_api_enable_mdlYesYesYes GlobalNo
innodb_api_trx_levelYesYesYes GlobalYes
innodb_autoextend_incrementYesYesYes GlobalYes
innodb_autoinc_lock_modeYesYesYes GlobalNo
Innodb_available_undo_logs   YesGlobalNo
innodb_background_drop_list_emptyYesYesYes GlobalYes
Innodb_buffer_pool_bytes_data   YesGlobalNo
Innodb_buffer_pool_bytes_dirty   YesGlobalNo
innodb_buffer_pool_chunk_sizeYesYesYes GlobalNo
innodb_buffer_pool_debugYesYesYes GlobalNo
innodb_buffer_pool_dump_at_shutdownYesYesYes GlobalYes
innodb_buffer_pool_dump_nowYesYesYes GlobalYes
innodb_buffer_pool_dump_pctYesYesYes GlobalYes
Innodb_buffer_pool_dump_status   YesGlobalNo
innodb_buffer_pool_filenameYesYesYes GlobalYes
innodb_buffer_pool_instancesYesYesYes GlobalNo
innodb_buffer_pool_load_abortYesYesYes GlobalYes
innodb_buffer_pool_load_at_startupYesYesYes GlobalNo
innodb_buffer_pool_load_nowYesYesYes GlobalYes
Innodb_buffer_pool_load_status   YesGlobalNo
Innodb_buffer_pool_pages_data   YesGlobalNo
Innodb_buffer_pool_pages_dirty   YesGlobalNo
Innodb_buffer_pool_pages_flushed   YesGlobalNo
Innodb_buffer_pool_pages_free   YesGlobalNo
Innodb_buffer_pool_pages_latched   YesGlobalNo
Innodb_buffer_pool_pages_misc   YesGlobalNo
Innodb_buffer_pool_pages_total   YesGlobalNo
Innodb_buffer_pool_read_ahead   YesGlobalNo
Innodb_buffer_pool_read_ahead_evicted   YesGlobalNo
Innodb_buffer_pool_read_ahead_rnd   YesGlobalNo
Innodb_buffer_pool_read_requests   YesGlobalNo
Innodb_buffer_pool_reads   YesGlobalNo
Innodb_buffer_pool_resize_status   YesGlobalNo
innodb_buffer_pool_sizeYesYesYes GlobalYes
Innodb_buffer_pool_wait_free   YesGlobalNo
Innodb_buffer_pool_write_requests   YesGlobalNo
innodb_change_buffer_max_sizeYesYesYes GlobalYes
innodb_change_bufferingYesYesYes GlobalYes
innodb_change_buffering_debugYesYesYes GlobalYes
innodb_checkpoint_disabledYesYesYes GlobalYes
innodb_checksum_algorithmYesYesYes GlobalYes
innodb_cmp_per_index_enabledYesYesYes GlobalYes
innodb_commit_concurrencyYesYesYes GlobalYes
innodb_compress_debugYesYesYes GlobalYes
innodb_compression_failure_threshold_pctYesYesYes GlobalYes
innodb_compression_levelYesYesYes GlobalYes
innodb_compression_pad_pct_maxYesYesYes GlobalYes
innodb_concurrency_ticketsYesYesYes GlobalYes
innodb_data_file_pathYesYesYes GlobalNo
Innodb_data_fsyncs   YesGlobalNo
innodb_data_home_dirYesYesYes GlobalNo
Innodb_data_pending_fsyncs   YesGlobalNo
Innodb_data_pending_reads   YesGlobalNo
Innodb_data_pending_writes   YesGlobalNo
Innodb_data_read   YesGlobalNo
Innodb_data_reads   YesGlobalNo
Innodb_data_writes   YesGlobalNo
Innodb_data_written   YesGlobalNo
Innodb_dblwr_pages_written   YesGlobalNo
Innodb_dblwr_writes   YesGlobalNo
innodb_ddl_log_crash_reset_debugYesYesYes GlobalYes
innodb_dedicated_serverYesYesYes GlobalNo
innodb_default_row_formatYesYesYes GlobalYes
innodb_disable_sort_file_cacheYesYesYes GlobalYes
innodb_doublewriteYesYesYes GlobalNo
innodb_fast_shutdownYesYesYes GlobalYes
innodb_fil_make_page_dirty_debugYesYesYes GlobalYes
innodb_file_per_tableYesYesYes GlobalYes
innodb_fill_factorYesYesYes GlobalYes
innodb_flush_log_at_timeout  Yes GlobalYes
innodb_flush_log_at_trx_commitYesYesYes GlobalYes
innodb_flush_methodYesYesYes GlobalNo
innodb_flush_neighborsYesYesYes GlobalYes
innodb_flush_syncYesYesYes GlobalYes
innodb_flushing_avg_loopsYesYesYes GlobalYes
innodb_force_load_corruptedYesYesYes GlobalNo
innodb_force_recoveryYesYesYes GlobalNo
innodb_ft_aux_tableYesYesYes GlobalYes
innodb_ft_cache_sizeYesYesYes GlobalNo
innodb_ft_enable_diag_printYesYesYes GlobalYes
innodb_ft_enable_stopwordYesYesYes GlobalYes
innodb_ft_max_token_sizeYesYesYes GlobalNo
innodb_ft_min_token_sizeYesYesYes GlobalNo
innodb_ft_num_word_optimizeYesYesYes GlobalYes
innodb_ft_result_cache_limitYesYesYes GlobalYes
innodb_ft_server_stopword_tableYesYesYes GlobalYes
innodb_ft_sort_pll_degreeYesYesYes GlobalNo
innodb_ft_total_cache_sizeYesYesYes GlobalNo
innodb_ft_user_stopword_tableYesYesYes BothYes
Innodb_have_atomic_builtins   YesGlobalNo
innodb_io_capacityYesYesYes GlobalYes
innodb_io_capacity_maxYesYesYes GlobalYes
innodb_limit_optimistic_insert_debugYesYesYes GlobalYes
innodb_lock_wait_timeoutYesYesYes BothYes
innodb_log_buffer_sizeYesYesYes GlobalNo
innodb_log_checksumsYesYesYes GlobalYes
innodb_log_compressed_pagesYesYesYes GlobalYes
innodb_log_file_sizeYesYesYes GlobalNo
innodb_log_files_in_groupYesYesYes GlobalNo
innodb_log_group_home_dirYesYesYes GlobalNo
Innodb_log_waits   YesGlobalNo
innodb_log_write_ahead_sizeYesYesYes GlobalYes
Innodb_log_write_requests   YesGlobalNo
Innodb_log_writes   YesGlobalNo
innodb_lru_scan_depthYesYesYes GlobalYes
innodb_max_dirty_pages_pctYesYesYes GlobalYes
innodb_max_dirty_pages_pct_lwmYesYesYes GlobalYes
innodb_max_purge_lagYesYesYes GlobalYes
innodb_max_purge_lag_delayYesYesYes GlobalYes
innodb_max_undo_log_sizeYesYesYes GlobalYes
innodb_merge_threshold_set_all_debugYesYesYes GlobalYes
innodb_monitor_disableYesYesYes GlobalYes
innodb_monitor_enableYesYesYes GlobalYes
innodb_monitor_resetYesYesYes GlobalYes
innodb_monitor_reset_allYesYesYes GlobalYes
Innodb_num_open_files   YesGlobalNo
innodb_numa_interleaveYesYesYes GlobalNo
innodb_old_blocks_pctYesYesYes GlobalYes
innodb_old_blocks_timeYesYesYes GlobalYes
innodb_online_alter_log_max_sizeYesYesYes GlobalYes
innodb_open_filesYesYesYes GlobalNo
innodb_optimize_fulltext_onlyYesYesYes GlobalYes
Innodb_os_log_fsyncs   YesGlobalNo
Innodb_os_log_pending_fsyncs   YesGlobalNo
Innodb_os_log_pending_writes   YesGlobalNo
Innodb_os_log_written   YesGlobalNo
innodb_page_cleanersYesYesYes GlobalNo
Innodb_page_size   YesGlobalNo
innodb_page_sizeYesYesYes GlobalNo
Innodb_pages_created   YesGlobalNo
Innodb_pages_read   YesGlobalNo
Innodb_pages_written   YesGlobalNo
innodb_print_all_deadlocksYesYesYes GlobalYes
innodb_print_ddl_logsYesYesYes GlobalYes
innodb_purge_batch_sizeYesYesYes GlobalYes
innodb_purge_rseg_truncate_frequencyYesYesYes GlobalYes
innodb_purge_threadsYesYesYes GlobalNo
innodb_random_read_aheadYesYesYes GlobalYes
innodb_read_ahead_thresholdYesYesYes GlobalYes
innodb_read_io_threadsYesYesYes GlobalNo
innodb_read_onlyYesYesYes GlobalNo
innodb_redo_log_encryptYesYesYes GlobalYes
innodb_replication_delayYesYesYes GlobalYes
innodb_rollback_on_timeoutYesYesYes GlobalNo
innodb_rollback_segmentsYesYesYes GlobalYes
Innodb_row_lock_current_waits   YesGlobalNo
Innodb_row_lock_time   YesGlobalNo
Innodb_row_lock_time_avg   YesGlobalNo
Innodb_row_lock_time_max   YesGlobalNo
Innodb_row_lock_waits   YesGlobalNo
Innodb_rows_deleted   YesGlobalNo
Innodb_rows_inserted   YesGlobalNo
Innodb_rows_read   YesGlobalNo
Innodb_rows_updated   YesGlobalNo
innodb_saved_page_number_debugYesYesYes GlobalYes
innodb_scan_directoriesYesYesYes GlobalNo
innodb_sort_buffer_sizeYesYesYes GlobalNo
innodb_spin_wait_delayYesYesYes GlobalYes
innodb_stats_auto_recalcYesYesYes GlobalYes
innodb_stats_include_delete_markedYesYesYes GlobalYes
innodb_stats_methodYesYesYes GlobalYes
innodb_stats_on_metadataYesYesYes GlobalYes
innodb_stats_persistentYesYesYes GlobalYes
innodb_stats_persistent_sample_pagesYesYesYes GlobalYes
innodb_stats_transient_sample_pagesYesYesYes GlobalYes
innodb-status-fileYesYes    
innodb_status_outputYesYesYes GlobalYes
innodb_status_output_locksYesYesYes GlobalYes
innodb_strict_modeYesYesYes BothYes
innodb_sync_array_sizeYesYesYes GlobalNo
innodb_sync_debugYesYesYes GlobalNo
innodb_sync_spin_loopsYesYesYes GlobalYes
innodb_table_locksYesYesYes BothYes
innodb_temp_data_file_pathYesYesYes GlobalNo
innodb_thread_concurrencyYesYesYes GlobalYes
innodb_thread_sleep_delayYesYesYes GlobalYes
innodb_tmpdirYesYesYes BothYes
Innodb_truncated_status_writes   YesGlobalNo
innodb_trx_purge_view_update_only_debugYesYesYes GlobalYes
innodb_trx_rseg_n_slots_debugYesYesYes GlobalYes
innodb_undo_directoryYesYesYes GlobalNo
innodb_undo_log_encryptYesYesYes GlobalYes
innodb_undo_log_truncateYesYesYes GlobalYes
innodb_undo_logsYesYesYes GlobalYes
innodb_undo_tablespacesYesYesYes GlobalVaries
innodb_use_native_aioYesYesYes GlobalNo
innodb_version  Yes GlobalNo
innodb_write_io_threadsYesYesYes GlobalNo
mecab_rc_fileYesYesYes GlobalNo
ngram_token_sizeYesYesYes GlobalNo
unique_checks  Yes BothYes

InnoDB Command Options

  • --ignore-builtin-innodb

    Deprecated5.5.22
    Removed8.0.3
    Command-Line Format--ignore-builtin-innodb
    System VariableNameignore_builtin_innodb
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean

    In MySQL 5.1, this option caused the server to behave as if the built-in InnoDB were not present, which enabled the InnoDB Plugin to be used instead. In MySQL 8.0, InnoDB is the default storage engine and InnoDB Plugin is not used. This option was removed in MySQL 8.0.

  • --innodb[=value]

    Deprecated5.7.5
    Command-Line Format--innodb[=value]
    Permitted ValuesTypeenumeration
    DefaultON
    Valid ValuesOFF
    ON
    FORCE

    Controls loading of the InnoDB storage engine, if the server was compiled with InnoDB support. This option has a tristate format, with possible values of OFF, ON, or FORCE. See Section 5.6.1, “Installing and Uninstalling Plugins”.

    To disable InnoDB, use --innodb=OFF or --skip-innodb. In this case, because the default storage engine is InnoDB, the server does not start unless you also use --default-storage-engine and --default-tmp-storage-engine to set the default to some other engine for both permanent and TEMPORARY tables.

    The InnoDB storage engine can no longer be disabled, and the --innodb=OFF and --skip-innodb options are deprecated and have no effect. Their use results in a warning. These options will be removed in a future MySQL release.

  • --innodb-status-file

    Command-Line Format--innodb-status-file
    Permitted ValuesTypeboolean
    DefaultOFF

    Controls whether InnoDB creates a file named innodb_status.pid in the MySQL data directory. If enabled, 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.

  • --skip-innodb

    Disable the InnoDB storage engine. See the description of --innodb.

InnoDB System Variables

  • daemon_memcached_enable_binlog

    Command-Line Format--daemon-memcached-enable-binlog=#
    System VariableNamedaemon_memcached_enable_binlog
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    Defaultfalse

    Enable this option on the master server to use the InnoDB memcached plugin (daemon_memcached) with the MySQL binary log. This option can only be set at server startup. You must also enable the MySQL binary log on the master server using the --log-bin option.

    For more information, see Section 15.19.7, “The InnoDB memcached Plugin and Replication”.

  • daemon_memcached_engine_lib_name

    Command-Line Format--daemon-memcached-engine-lib-name=library
    System VariableNamedaemon_memcached_engine_lib_name
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypefile name
    Defaultinnodb_engine.so

    Specifies the shared library that implements the InnoDB memcached plugin.

    For more information, see Section 15.19.3, “Setting Up the InnoDB memcached Plugin”.

  • daemon_memcached_engine_lib_path

    Command-Line Format--daemon-memcached-engine-lib-path=directory
    System VariableNamedaemon_memcached_engine_lib_path
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypedirectory name
    DefaultNULL

    The path of the directory containing the shared library that implements the InnoDB memcached plugin. The default value is NULL, representing the MySQL plugin directory. You should not need to modify this parameter unless specifying a memcached plugin for a different storage engine that is located outside of the MySQL plugin directory.

    For more information, see Section 15.19.3, “Setting Up the InnoDB memcached Plugin”.

  • daemon_memcached_option

    Command-Line Format--daemon-memcached-option=options
    System VariableNamedaemon_memcached_option
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypestring
    Default

    Used to pass space-separated memcached options to the underlying memcached memory object caching daemon on startup. For example, you might change the port that memcached listens on, reduce the maximum number of simultaneous connections, change the maximum memory size for a key/value pair, or enable debugging messages for the error log.

    See Section 15.19.3, “Setting Up the InnoDB memcached Plugin” for usage details. For information about memcached options, refer to the memcached man page.

  • daemon_memcached_r_batch_size

    Command-Line Format--daemon-memcached-r-batch-size=#
    System VariableNamedaemon_memcached_r_batch_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default1

    Specifies how many memcached read operations (get operations) to perform before doing a COMMIT to start a new transaction. Counterpart of daemon_memcached_w_batch_size.

    This value is set to 1 by default, so that any changes made to the table through SQL statements are immediately visible to memcached operations. You might increase it to reduce the overhead from frequent commits on a system where the underlying table is only being accessed through the memcached interface. If you set the value too large, the amount of undo or redo data could impose some storage overhead, as with any long-running transaction.

    For more information, see Section 15.19.3, “Setting Up the InnoDB memcached Plugin”.

  • daemon_memcached_w_batch_size

    Command-Line Format--daemon-memcached-w-batch-size=#
    System VariableNamedaemon_memcached_w_batch_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default1

    Specifies how many memcached write operations, such as add, set, and incr, to perform before doing a COMMIT to start a new transaction. Counterpart of daemon_memcached_r_batch_size.

    This value is set to 1 by default, on the assumption that data being stored is important to preserve in case of an outage and should immediately be committed. When storing non-critical data, you might increase this value to reduce the overhead from frequent commits; but then the last N-1 uncommitted write operations could be lost if a crash occurs.

    For more information, see Section 15.19.3, “Setting Up the InnoDB memcached Plugin”.

  • ignore_builtin_innodb

    Deprecated5.5.22
    Removed8.0.3
    Command-Line Format--ignore-builtin-innodb
    System VariableNameignore_builtin_innodb
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean

    See the description of --ignore-builtin-innodb under InnoDB Command Options earlier in this section. This variable was removed in MySQL 8.0.

  • innodb_adaptive_flushing

    Command-Line Format--innodb-adaptive-flushing=#
    System VariableNameinnodb_adaptive_flushing
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Specifies whether to dynamically adjust the rate of flushing dirty pages in the InnoDB buffer 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 15.6.3.6, “Configuring InnoDB Buffer Pool Flushing” for more information. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_adaptive_flushing_lwm

    Command-Line Format--innodb-adaptive-flushing-lwm=#
    System VariableNameinnodb_adaptive_flushing_lwm
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default10
    Minimum0
    Maximum70

    Defines the low water mark representing percentage of redo log capacity at which adaptive flushing is enabled. For more information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”.

  • innodb_adaptive_hash_index

    Command-Line Format--innodb-adaptive-hash-index=#
    System VariableNameinnodb_adaptive_hash_index
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Whether the InnoDB adaptive 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 15.4.3, “Adaptive Hash Index” for details.

    This variable is enabled by default. You can modify this parameter using the SET GLOBAL statement, without restarting the server. Changing the setting requires the SYSTEM_VARIABLES_ADMIN or SUPER privilege. You can also use --skip-innodb_adaptive_hash_index at 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_adaptive_hash_index_parts

    Command-Line Format--innodb-adaptive-hash-index-parts=#
    System VariableNameinnodb_adaptive_hash_index_parts
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypenumeric
    Default8
    Minimum1
    Maximum512

    Partitions the adaptive hash index search system. Each index is bound to a specific partition, with each partition protected by a separate latch.

    The adaptive hash index search system is partitioned into 8 parts by default. The maximum setting is 512.

    For related information, see Section 15.4.3, “Adaptive Hash Index”.

  • innodb_adaptive_max_sleep_delay

    Command-Line Format--innodb-adaptive-max-sleep-delay=#
    System VariableNameinnodb_adaptive_max_sleep_delay
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default150000
    Minimum0
    Maximum1000000

    Permits InnoDB to automatically adjust the value of innodb_thread_sleep_delay up or down according to the current workload. Any non-zero value enables automated, dynamic adjustment of the innodb_thread_sleep_delay value, up to the maximum value specified in the innodb_adaptive_max_sleep_delay option. The value represents the number of microseconds. This option can be useful in busy systems, with greater than 16 InnoDB threads. (In practice, it is most valuable for MySQL systems with hundreds or thousands of simultaneous connections.)

    For more information, see Section 15.6.5, “Configuring Thread Concurrency for InnoDB”.

  • innodb_api_bk_commit_interval

    Command-Line Format--innodb-api-bk-commit-interval=#
    System VariableNameinnodb_api_bk_commit_interval
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default5
    Minimum1
    Maximum1073741824

    How often to auto-commit idle connections that use the InnoDB memcached interface, in seconds. For more information, see Section 15.19.6.4, “Controlling Transactional Behavior of the InnoDB memcached Plugin”.

  • innodb_api_disable_rowlock

    Command-Line Format--innodb-api-disable-rowlock=#
    System VariableNameinnodb_api_disable_rowlock
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Use this option to disable row locks when InnoDB memcached performs DML operations. By default, innodb_api_disable_rowlock is disabled, which means that memcached requests row locks for get and set operations. When innodb_api_disable_rowlock is enabled, memcached requests a table lock instead of row locks.

    innodb_api_disable_rowlock is not dynamic. It must be specified on the mysqld command line or entered in the MySQL configuration file. Configuration takes effect when the plugin is installed, which occurs when the MySQL server is started.

    For more information, see Section 15.19.6.4, “Controlling Transactional Behavior of the InnoDB memcached Plugin”.

  • innodb_api_enable_binlog

    Command-Line Format--innodb-api-enable-binlog=#
    System VariableNameinnodb_api_enable_binlog
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Lets you use the InnoDB memcached plugin with the MySQL binary log. For more information, see Enabling the InnoDB memcached Binary Log.

  • innodb_api_enable_mdl

    Command-Line Format--innodb-api-enable-mdl=#
    System VariableNameinnodb_api_enable_mdl
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Locks the table used by the InnoDB memcached plugin, so that it cannot be dropped or altered by DDL through the SQL interface. For more information, see Section 15.19.6.4, “Controlling Transactional Behavior of the InnoDB memcached Plugin”.

  • innodb_api_trx_level

    Command-Line Format--innodb-api-trx-level=#
    System VariableNameinnodb_api_trx_level
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0

    Controls the transaction isolation level on queries processed by the memcached interface. The constants corresponding to the familiar names are:

    For more information, see Section 15.19.6.4, “Controlling Transactional Behavior of the InnoDB memcached Plugin”.

  • innodb_autoextend_increment

    Command-Line Format--innodb-autoextend-increment=#
    System VariableNameinnodb_autoextend_increment
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default64
    Minimum1
    Maximum1000

    The increment size (in megabytes) for extending the size of an auto-extending InnoDB system tablespace file when it becomes full. The default value is 64. For related information, see System Tablespace Data File Configuration, and Section 15.7.1, “Resizing the InnoDB System Tablespace”.

    The innodb_autoextend_increment setting does not affect file-per-table tablespace files or general tablespace files. These files are auto-extending regardless of the innodb_autoextend_increment setting. The initial extensions are by small amounts, after which extensions occur in increments of 4MB.

  • innodb_autoinc_lock_mode

    Command-Line Format--innodb-autoinc-lock-mode=#
    System VariableNameinnodb_autoinc_lock_mode
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted Values (<= 8.0.2)Typeinteger
    Default1
    Valid Values0
    1
    2
    Permitted Values (>= 8.0.3)Typeinteger
    Default2
    Valid Values0
    1
    2

    The 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 2 (interleaved) as of MySQL 8.0, and 1 (consecutive) before that. The change to interleaved lock mode as the default setting reflects the change from statement-based to row-based replication as the default replication type, which occurred in MySQL 5.7. Statement-based replication requires the consecutive auto-increment lock mode to ensure that auto-increment values are assigned in a predictable and repeatable order for a given sequence of SQL statements, whereas row-based replication is not sensitive to the execution order of SQL statements.

    For the characteristics of each lock mode, see InnoDB AUTO_INCREMENT Lock Modes.

  • innodb_background_drop_list_empty

    Command-Line Format--innodb-background-drop-list-empty=#
    System VariableNameinnodb_background_drop_list_empty
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enabling the innodb_background_drop_list_empty debug option helps avoid test case failures by delaying table creation until the background drop list is empty. For example, if test case A places table t1 on the background drop list, test case B waits until the background drop list is empty before creating table t1.

  • innodb_buffer_pool_chunk_size

    Command-Line Format--innodb-buffer-pool-chunk-size
    System VariableNameinnodb_buffer_pool_chunk_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default134217728
    Minimum1048576
    Maximuminnodb_buffer_pool_size / innodb_buffer_pool_instances

    innodb_buffer_pool_chunk_size defines the chunk size for InnoDB buffer pool resizing operations. The innodb_buffer_pool_size parameter is dynamic, which allows you to resize the buffer pool without restarting the server.

    To avoid copying all buffer pool pages during resizing operations, the operation is performed in chunks. By default, innodb_buffer_pool_chunk_size is 128MB (134217728 bytes). The number of pages contained in a chunk depends on the value of innodb_page_size. innodb_buffer_pool_chunk_size can be increased or decreased in units of 1MB (1048576 bytes).

    The following conditions apply when altering the innodb_buffer_pool_chunk_size value:

    Important

    Care should be taken when changing innodb_buffer_pool_chunk_size, as changing this value can automatically increase the size of the buffer pool. Before changing innodb_buffer_pool_chunk_size, calculate the effect it will have on innodb_buffer_pool_size to ensure that the resulting buffer pool size is acceptable.

    To avoid potential performance issues, the number of chunks (innodb_buffer_pool_size / innodb_buffer_pool_chunk_size) should not exceed 1000.

    See Section 15.6.3.2, “Configuring InnoDB Buffer Pool Size” for more information.

  • innodb_buffer_pool_debug

    Command-Line Format--innodb-buffer-pool-debug=#
    System VariableNameinnodb_buffer_pool_debug
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enabling this option permits multiple buffer pool instances when the buffer pool is less than 1GB in size, ignoring the 1GB minimum buffer pool size constraint imposed on innodb_buffer_pool_instances. The innodb_buffer_pool_debug option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_buffer_pool_dump_at_shutdown

    Command-Line Format--innodb-buffer-pool-dump-at-shutdown=#
    System VariableNameinnodb_buffer_pool_dump_at_shutdown
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Specifies whether to record the pages cached in the InnoDB buffer pool when the MySQL server is shut down, to shorten the warmup process at the next restart. Typically used in combination with innodb_buffer_pool_load_at_startup. The innodb_buffer_pool_dump_pct option defines the percentage of most recently used buffer pool pages to dump.

    Both innodb_buffer_pool_dump_at_shutdown and innodb_buffer_pool_load_at_startup are enabled by default.

    For more information, see Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

  • innodb_buffer_pool_dump_now

    Command-Line Format--innodb-buffer-pool-dump-now=#
    System VariableNameinnodb_buffer_pool_dump_now
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Immediately records the pages cached in the InnoDB buffer pool. Typically used in combination with innodb_buffer_pool_load_now.

    For more information, see Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

  • innodb_buffer_pool_dump_pct

    Command-Line Format--innodb-buffer-pool-dump-pct=#
    System VariableNameinnodb_buffer_pool_dump_pct
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default25
    Minimum1
    Maximum100

    Specifies the percentage of the most recently used pages for each buffer pool to read out and dump. The range is 1 to 100. The default value is 25. For example, if there are 4 buffer pools with 100 pages each, and innodb_buffer_pool_dump_pct is set to 25, the 25 most recently used pages from each buffer pool are dumped.

  • innodb_buffer_pool_filename

    Command-Line Format--innodb-buffer-pool-filename=file
    System VariableNameinnodb_buffer_pool_filename
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypefile name
    Defaultib_buffer_pool

    Specifies the name of the file that holds the list of tablespace IDs and page IDs produced by innodb_buffer_pool_dump_at_shutdown or innodb_buffer_pool_dump_now. Tablespace IDs and page IDs are saved in the following format: space, page_id. By default, the file is named ib_buffer_pool and is located in the InnoDB data directory. A non-default location must be specified relative to the data directory.

    A file name can be specified at runtime, using a SET statement:

    SET GLOBAL innodb_buffer_pool_filename='file_name';

    You can also specify a file name at startup, in a startup string or MySQL configuration file. When specifying a file name at startup, the file must exist or InnoDB will return a startup error indicating that there is no such file or directory.

    For more information, see Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

  • innodb_buffer_pool_instances

    Command-Line Format--innodb-buffer-pool-instances=#
    System VariableNameinnodb_buffer_pool_instances
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted Values (Windows, 32-bit platforms)Typeinteger
    Default(autosized)
    Minimum1
    Maximum64
    Permitted Values (Other)Typeinteger
    Default8 (or 1 if innodb_buffer_pool_size < 1GB
    Minimum1
    Maximum64

    The number of regions that the InnoDB buffer pool is divided into. For systems with buffer pools in the multi-gigabyte range, dividing the buffer pool into separate instances can improve concurrency, by reducing contention as different threads read and write to cached pages. Each page that is stored in or read from the buffer pool is assigned to one of the buffer pool instances randomly, using a hashing function. Each buffer pool manages its own free lists, flush lists, LRUs, and all other data structures connected to a buffer pool, and is protected by its own buffer pool mutex.

    This option only takes effect when setting innodb_buffer_pool_size to 1GB or more. The total buffer pool size is divided among all the buffer pools. For best efficiency, specify a combination of innodb_buffer_pool_instances and innodb_buffer_pool_size so that each buffer pool instance is at least 1GB.

    The default value on 32-bit Windows systems depends on the value of innodb_buffer_pool_size, as described below:

    • If innodb_buffer_pool_size is greater than 1.3GB, the default for innodb_buffer_pool_instances is innodb_buffer_pool_size/128MB, with individual memory allocation requests for each chunk. 1.3GB was chosen as the boundary at which there is significant risk for 32-bit Windows to be unable to allocate the contiguous address space needed for a single buffer pool.

    • Otherwise, the default is 1.

    On all other platforms, the default value is 8 when innodb_buffer_pool_size is greater than or equal to 1GB. Otherwise, the default is 1.

    For related information, see Section 15.6.3.2, “Configuring InnoDB Buffer Pool Size”.

  • innodb_buffer_pool_load_abort

    Command-Line Format--innodb-buffer-pool-load-abort=#
    System VariableNameinnodb_buffer_pool_load_abort
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Interrupts the process of restoring InnoDB buffer pool contents triggered by innodb_buffer_pool_load_at_startup or innodb_buffer_pool_load_now.

    For more information, see Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

  • innodb_buffer_pool_load_at_startup

    Command-Line Format--innodb-buffer-pool-load-at-startup=#
    System VariableNameinnodb_buffer_pool_load_at_startup
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Specifies that, on MySQL server startup, the InnoDB buffer pool is automatically warmed up by loading the same pages it held at an earlier time. Typically used in combination with innodb_buffer_pool_dump_at_shutdown.

    Both innodb_buffer_pool_dump_at_shutdown and innodb_buffer_pool_load_at_startup are enabled by default.

    For more information, see Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

  • innodb_buffer_pool_load_now

    Command-Line Format--innodb-buffer-pool-load-now=#
    System VariableNameinnodb_buffer_pool_load_now
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Immediately warms up the InnoDB buffer pool by loading a set of data pages, without waiting for a server restart. Can be useful to bring cache memory back to a known state during benchmarking, or to ready the MySQL server to resume its normal workload after running queries for reports or maintenance.

    For more information, see Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

  • innodb_buffer_pool_size

    Command-Line Format--innodb-buffer-pool-size=#
    System VariableNameinnodb_buffer_pool_size
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default134217728
    Minimum5242880
    Maximum2**32-1
    Permitted Values (64-bit platforms)Typeinteger
    Default134217728
    Minimum5242880
    Maximum2**64-1

    The size in bytes of the buffer pool, the memory area where InnoDB caches table and index data. The default value is 134217728 bytes (128MB). The maximum value depends on the CPU architecture; the maximum is 4294967295 (232-1) on 32-bit systems and 18446744073709551615 (264-1) on 64-bit systems. On 32-bit systems, the CPU architecture and operating system may impose a lower practical maximum size than the stated maximum. When the size of the buffer pool is greater than 1GB, setting innodb_buffer_pool_instances to a value greater than 1 can improve the scalability on a busy server.

    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.

    • InnoDB reserves 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. To reduce the initialization period, you can save the buffer pool state at server shutdown and restore it at server startup. See Section 15.6.3.8, “Saving and Restoring the Buffer Pool State”.

    When you increase or decrease buffer pool size, the operation is performed in chunks. Chunk size is defined by the innodb_buffer_pool_chunk_size configuration option, which has a default of 128 MB.

    Buffer pool size must always be equal to or a multiple of innodb_buffer_pool_chunk_size * innodb_buffer_pool_instances. If you alter the buffer pool size to a value that is not equal to or a multiple of innodb_buffer_pool_chunk_size * innodb_buffer_pool_instances, buffer pool size is automatically adjusted to a value that is equal to or a multiple of innodb_buffer_pool_chunk_size * innodb_buffer_pool_instances that is not less than the specified buffer pool size.

    innodb_buffer_pool_size can be set dynamically, which allows you to resize the buffer pool without restarting the server. The Innodb_buffer_pool_resize_status status variable reports the status of online buffer pool resizing operations. See Section 15.6.3.2, “Configuring InnoDB Buffer Pool Size” for more information.

    If innodb_dedicated_server is enabled, the innodb_buffer_pool_size value is automatically configured if it is not explicitly defined. For more information, see Section 15.6.13, “Enabling Automatic Configuration for a Dedicated MySQL Server”.

  • innodb_change_buffer_max_size

    Command-Line Format--innodb-change-buffer-max-size=#
    System VariableNameinnodb_change_buffer_max_size
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default25
    Minimum0
    Maximum50

    Maximum size for the InnoDB change buffer, as a percentage of the total size of the buffer pool. You might increase this value for a MySQL server with heavy insert, update, and delete activity, or decrease it for a MySQL server with unchanging data used for reporting. For more information, see Section 15.4.2, “Change Buffer”, and Section 15.6.4, “Configuring InnoDB Change Buffering”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_change_buffering

    Command-Line Format--innodb-change-buffering=#
    System VariableNameinnodb_change_buffering
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeenumeration
    Defaultall
    Valid Valuesnone
    inserts
    deletes
    changes
    purges
    all

    Whether InnoDB performs 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. Values may also be specified numerically.

    Table 15.15 Permitted Values for innodb_change_buffering

    ValueNumeric ValueDescription
    none0Do not buffer any operations.
    inserts1Buffer insert operations.
    deletes2Buffer delete marking operations; strictly speaking, the writes that mark index records for later deletion during a purge operation.
    changes3Buffer inserts and delete-marking operations.
    purges4Buffer the physical deletion operations that happen in the background.
    all5The default. Buffer inserts, delete-marking operations, and purges.

    For more information, see Section 15.4.2, “Change Buffer”, and Section 15.6.4, “Configuring InnoDB Change Buffering”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_change_buffering_debug

    Command-Line Format--innodb-change-buffering-debug=#
    System VariableNameinnodb_change_buffering_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Maximum2

    Sets a debug flag for InnoDB change 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 the WITH_DEBUG CMake option.

  • innodb_checkpoint_disabled

    Introduced8.0.2
    Command-Line Format--innodb-checkpoint-disabled=#
    System VariableNameinnodb_checkpoint_disabled
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    This is a debug option that is only intended for expert debugging use. It disables checkpoints so that a deliberate server exit always initiates InnoDB recovery. It should only be enabled for a short interval, typically before running DML operations that write redo log entries that would require recovery following a server exit. This option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_checksum_algorithm

    Command-Line Format--innodb-checksum-algorithm=#
    System VariableNameinnodb_checksum_algorithm
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeenumeration
    Defaultcrc32
    Valid Valuesinnodb
    crc32
    none
    strict_innodb
    strict_crc32
    strict_none

    Specifies how to generate and verify the checksum stored in the disk blocks of InnoDB tablespaces. The default value for innodb_checksum_algorithm is crc32.

    Versions of MySQL Enterprise Backup up to 3.8.0 do not support backing up tablespaces that use CRC32 checksums. MySQL Enterprise Backup adds CRC32 checksum support in 3.8.1, with some limitations. Refer to the MySQL Enterprise Backup 3.8.1 Change History for more information.

    The value innodb is backward-compatible with earlier versions of MySQL. The value crc32 uses an algorithm that is faster to compute the checksum for every modified block, and to check the checksums for each disk read. It scans blocks 32 bits at a time, which is faster than the innodb checksum algorithm, which scans blocks 8 bits at a time. The value none writes a constant value in the checksum field rather than computing a value based on the block data. The blocks in a tablespace can use a mix of old, new, and no checksum values, being updated gradually as the data is modified; once blocks in a tablespace are modified to use the crc32 algorithm, the associated tables cannot be read by earlier versions of MySQL.

    The strict form of a checksum algorithm reports an error if it encounters a valid but non-matching checksum value in a tablespace. It is recommended that you only use strict settings in a new instance, to set up tablespaces for the first time. Strict settings are somewhat faster, because they do not need to compute all checksum values during disk reads.

    The following table shows the difference between the none, innodb, and crc32 option values, and their strict counterparts. none, innodb, and crc32 write the specified type of checksum value into each data block, but for compatibility accept other checksum values when verifying a block during a read operation. Strict settings also accept valid checksum values but print an error message when a valid non-matching checksum value is encountered. Using the strict form can make verification faster if all InnoDB data files in an instance are created under an identical innodb_checksum_algorithm value.

    Table 15.16 innodb_checksum_algorithm Settings

    ValueGenerated checksum (when writing)Permitted checksums (when reading)
    noneA constant number.Any of the checksums generated by none, innodb, or crc32.
    innodbA checksum calculated in software, using the original algorithm from InnoDB.Any of the checksums generated by none, innodb, or crc32.
    crc32A checksum calculated using the crc32 algorithm, possibly done with a hardware assist.Any of the checksums generated by none, innodb, or crc32.
    strict_noneA constant numberAny of the checksums generated by none, innodb, or crc32. InnoDB prints an error message if a valid but non-matching checksum is encountered.
    strict_innodbA checksum calculated in software, using the original algorithm from InnoDB.Any of the checksums generated by none, innodb, or crc32. InnoDB prints an error message if a valid but non-matching checksum is encountered.
    strict_crc32A checksum calculated using the crc32 algorithm, possibly done with a hardware assist.Any of the checksums generated by none, innodb, or crc32. InnoDB prints an error message if a valid but non-matching checksum is encountered.

  • innodb_cmp_per_index_enabled

    Command-Line Format--innodb-cmp-per-index-enabled=#
    System VariableNameinnodb_cmp_per_index_enabled
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF
    Valid ValuesOFF
    ON

    Enables per-index compression-related statistics in the INFORMATION_SCHEMA.INNODB_CMP_PER_INDEX table. Because these statistics can be expensive to gather, only enable this option on development, test, or slave instances during performance tuning related to InnoDB compressed tables.

    For more information, see Section 25.32.7, “The INFORMATION_SCHEMA INNODB_CMP_PER_INDEX and INNODB_CMP_PER_INDEX_RESET Tables”, and Section 15.9.1.4, “Monitoring InnoDB Table Compression at Runtime”.

  • innodb_commit_concurrency

    Command-Line Format--innodb-commit-concurrency=#
    System VariableNameinnodb_commit_concurrency
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0
    Maximum1000

    The number of threads that can commit at the same time. A value of 0 (the default) permits any number of transactions to commit simultaneously.

    The value of innodb_commit_concurrency cannot be changed at runtime from zero to nonzero or vice versa. The value can be changed from one nonzero value to another.

  • innodb_compress_debug

    Command-Line Format--innodb-compress-debug=#
    System VariableNameinnodb_compress_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeenumeration
    Defaultnone
    Valid Valuesnone
    zlib
    lz4
    lz4hc

    Compresses all tables using a specified compression algorithm without having to define a COMPRESSION attribute for each table. This option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

    For related information, see Section 15.9.2, “InnoDB Page Compression”.

  • innodb_compression_failure_threshold_pct

    Command-Line Format--innodb-compression-failure-threshold-pct=#
    System VariableNameinnodb_compression_failure_threshold_pct
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default5
    Minimum0
    Maximum100

    Defines the compression failure rate threshold for a table, as a percentage, at which point MySQL begins adding padding within compressed pages to avoid expensive compression failures. When this threshold is passed, MySQL begins to leave additional free space within each new compressed page, dynamically adjusting the amount of free space up to the percentage of page size specified by innodb_compression_pad_pct_max. A value of zero disables the mechanism that monitors compression efficiency and dynamically adjusts the padding amount.

    For more information, see Section 15.9.1.6, “Compression for OLTP Workloads”.

  • innodb_compression_level

    Command-Line Format--innodb-compression-level=#
    System VariableNameinnodb_compression_level
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default6
    Minimum0
    Maximum9

    Specifies the level of zlib compression to use for InnoDB compressed tables and indexes. A higher value lets you fit more data onto a storage device, at the expense of more CPU overhead during compression. A lower value lets you reduce CPU overhead when storage space is not critical, or you expect the data is not especially compressible.

    For more information, see Section 15.9.1.6, “Compression for OLTP Workloads”.

  • innodb_compression_pad_pct_max

    Command-Line Format--innodb-compression-pad-pct-max=#
    System VariableNameinnodb_compression_pad_pct_max
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default50
    Minimum0
    Maximum75

    Specifies the maximum percentage that can be reserved as free space within each compressed page, allowing room to reorganize the data and modification log within the page when a compressed table or index is updated and the data might be recompressed. Only applies when innodb_compression_failure_threshold_pct is set to a non-zero value, and the rate of compression failures passes the cutoff point.

    For more information, see Section 15.9.1.6, “Compression for OLTP Workloads”.

  • innodb_concurrency_tickets

    Command-Line Format--innodb-concurrency-tickets=#
    System VariableNameinnodb_concurrency_tickets
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default5000
    Minimum1
    Maximum4294967295

    Determines the number of threads that can enter InnoDB concurrently. A thread is placed in a queue when it tries to enter InnoDB if the number of threads has already reached the concurrency limit. When a thread is permitted to enter InnoDB, it is given a number of 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 5000.

    With a small innodb_concurrency_tickets value, small transactions that only need to process a few rows compete fairly with larger transactions that process many rows. The disadvantage of a small innodb_concurrency_tickets value 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_tickets value, large transactions spend less time waiting for a position at the end of the queue (controlled by innodb_thread_concurrency) and more time retrieving rows. Large transactions also require fewer trips through the queue to complete their task. The disadvantage of a large innodb_concurrency_tickets value 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_concurrency value, you may need to adjust the innodb_concurrency_tickets value up or down to find the optimal balance between larger and smaller transactions. The SHOW ENGINE INNODB STATUS report shows the number of tickets remaining for an executing transaction in its current pass through the queue. This data may also be obtained from the TRX_CONCURRENCY_TICKETS column of the INFORMATION_SCHEMA.INNODB_TRX table.

    For more information, see Section 15.6.5, “Configuring Thread Concurrency for InnoDB”.

  • innodb_data_file_path

    Command-Line Format--innodb-data-file-path=name
    System VariableNameinnodb_data_file_path
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypestring
    Defaultibdata1:12M:autoextend

    Defines the name, size, and attributes of InnoDB system tablespace data files. If you do not specify a value for innodb_data_file_path, the default behavior is to create a single auto-extending data file, slightly larger than 12MB, named ibdata1.

    The full syntax for a data file specification includes the file name, file size, and autoextend and max attributes:

    file_name:file_size[:autoextend[:max:max_file_size]]

    File sizes are specified KB, MB or GB (1024MB) by appending K, M or G to 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 12MB.

    A minimum file size is enforced for the first system tablespace data file to ensure that there is enough space for doublewrite buffer pages:

    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.

    The autoextend and max attributes can be used only for the data file that is specified last in the innodb_data_file_path setting. For example:

    [mysqld]
    innodb_data_file_path=ibdata1:50M;ibdata2:12M:autoextend:max:500MB

    If you specify the autoextend option, InnoDB extends the data file if it runs out of free space. The autoextend increment is 64MB by default. To modify the increment, change the innodb_autoextend_increment system variable.

    The full directory path for system tablespace data files is formed by concatenating the paths defined by innodb_data_home_dir and innodb_data_file_path.

    For more information about configuring system tablespace data files, see Section 15.6.1, “InnoDB Startup Configuration”.

  • innodb_data_home_dir

    Command-Line Format--innodb-data-home-dir=dir_name
    System VariableNameinnodb_data_home_dir
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypedirectory name

    The common part of the directory path for InnoDB system tablespace data files. This setting does not affect the location of file-per-table 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 specify an absolute file paths for innodb_data_file_path.

    A trailing slash is required when specifying a value for innodb_data_home_dir. For example:

    [mysqld]
    innodb_data_home_dir = /path/to/myibdata/

    For related information, see Section 15.6.1, “InnoDB Startup Configuration”.

  • innodb_ddl_log_crash_reset_debug

    Introduced8.0.3
    Command-Line Format--innodb-ddl-log-crash-reset-debug=#
    System VariableNameinnodb_ddl_log_crash_reset_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultFalse

    Enable this debug option to reset DDL log crash injection counters to 1. This option is only available when debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_deadlock_detect

    Command-Line Format--innodb-deadlock-detect
    System VariableNameinnodb_deadlock_detect
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    This option is used to disable deadlock detection. On high concurrency systems, deadlock detection can cause a slowdown when numerous threads wait for the same lock. At times, it may be more efficient to disable deadlock detection and rely on the innodb_lock_wait_timeout setting for transaction rollback when a deadlock occurs.

    For related information, see Section 15.5.5.2, “Deadlock Detection and Rollback”.

  • innodb_dedicated_server

    Introduced8.0.3
    Command-Line Format--innodb-dedicated-server=#
    System VariableNameinnodb_dedicated_server
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    When innodb_dedicated_server is enabled, InnoDB automatically configures the following options according to the amount of memory detected on the server:

    Only consider enabling this option if your MySQL instance runs on a dedicated server where the MySQL server is able to consume all available system resources. Enabling this option is not recommended if your MySQL instance shares system resources with other applications.

    For more information, see Section 15.6.13, “Enabling Automatic Configuration for a Dedicated MySQL Server”.

  • innodb_default_row_format

    Command-Line Format--innodb-default-row-format=#
    System VariableNameinnodb_default_row_format
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeenumeration
    DefaultDYNAMIC
    Valid ValuesDYNAMIC
    COMPACT
    REDUNDANT

    The innodb_default_row_format option defines the default row format for InnoDB tables and user-created temporary tables. The default setting is DYNAMIC. Other permitted values are COMPACT and REDUNDANT. The COMPRESSED row format, which is not supported for use in the system tablespace, cannot be defined as the default.

    Newly created tables use the row format defined by innodb_default_row_format when a ROW_FORMAT option is not specified explicitly or when ROW_FORMAT=DEFAULT is used.

    When a ROW_FORMAT option is not specified explicitly or when ROW_FORMAT=DEFAULT is used, any operation that rebuilds a table also silently changes the row format of the table to the format defined by innodb_default_row_format. For more information, see Section 15.10.2, “Specifying the Row Format for a Table”.

    Internal InnoDB temporary tables created by the server to process queries use the DYNAMIC row format, regardless of the innodb_default_row_format setting.

  • innodb_disable_sort_file_cache

    Command-Line Format--innodb-disable-sort-file-cache=#
    System VariableNameinnodb_disable_sort_file_cache
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Disables the operating system file system cache for merge-sort temporary files. The effect is to open such files with the equivalent of O_DIRECT.

  • innodb_doublewrite

    Command-Line Format--innodb-doublewrite
    System VariableNameinnodb_doublewrite
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    When enabled (the default), InnoDB stores all data twice, first to the doublewrite buffer, 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.

    If system tablespace data files (ibdata* files) are located on Fusion-io devices that support atomic writes, doublewrite buffering is automatically disabled and Fusion-io atomic writes are used for all data files. Because the doublewrite buffer setting is global, doublewrite buffering is also disabled for data files residing on non-Fusion-io hardware. This feature is only supported on Fusion-io hardware and only enabled for Fusion-io NVMFS on Linux. To take full advantage of this feature, an innodb_flush_method setting of O_DIRECT is recommended.

    For related information, see Section 15.4.6, “Doublewrite Buffer”.

  • innodb_fast_shutdown

    Command-Line Format--innodb-fast-shutdown[=#]
    System VariableNameinnodb_fast_shutdown
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default1
    Valid Values0
    1
    2

    The InnoDB shutdown mode. If the value is 0, InnoDB does a slow shutdown, a full purge and a change buffer merge before shutting down. If the value is 1 (the default), InnoDB skips these operations at shutdown, a process known as a fast shutdown. If the value is 2, InnoDB flushes its logs and shuts down cold, as if MySQL had crashed; no committed transactions are lost, but the crash recovery operation makes the next startup take longer.

    The slow shutdown can take minutes, or even hours in extreme cases where substantial amounts of data are still buffered. Use the slow shutdown technique before upgrading or downgrading between MySQL major releases, so that all data files are fully prepared in case the upgrade process updates the file format.

    Use innodb_fast_shutdown=2 in emergency or troubleshooting situations, to get the absolute fastest shutdown if data is at risk of corruption.

  • innodb_fil_make_page_dirty_debug

    Command-Line Format--innodb-fil-make-page-dirty-debug=#
    System VariableNameinnodb_fil_make_page_dirty_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Maximum2**32-1

    By default, setting innodb_fil_make_page_dirty_debug to the ID of a tablespace immediately dirties the first page of the tablespace. If innodb_saved_page_number_debug is set to a non-default value, setting innodb_fil_make_page_dirty_debug dirties the specified page. The innodb_fil_make_page_dirty_debug option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_file_per_table

    Command-Line Format--innodb-file-per-table
    System VariableNameinnodb_file_per_table
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    When innodb_file_per_table is enabled (the default), InnoDB stores the data and indexes for each newly created table in a separate .ibd file instead of the system tablespace. The storage for these tables is reclaimed when the tables are dropped or truncated. This setting enables InnoDBfeatures such as table compression. See Section 15.7.4, “InnoDB File-Per-Table Tablespaces” for more information.

    Enabling innodb_file_per_table also means that an ALTER TABLE operation moves an InnoDB table from the system tablespace to an individual .ibd file in cases where ALTER TABLE rebuilds the table (ALGORITHM=COPY). An exception to this rule is for tables placed in the system tablespace using the TABLESPACE=innodb_system option with CREATE TABLE or ALTER TABLE. These tables are unaffected by the innodb_file_per_table setting and can only be moved to file-per-table tablespaces using ALTER TABLE ... TABLESPACE=innodb_file_per_table.

    When innodb_file_per_table is disabled, InnoDB stores the data for tables and indexes in the ibdata files that make up the system tablespace. This setting reduces the performance overhead of file system operations for operations such as DROP TABLE or TRUNCATE 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 when innodb_file_per_table is disabled. Set up a separate instance in such cases, so that you can drop the entire instance to reclaim the space.

    innodb_file_per_table is enabled by default. Consider disabling it if backward compatibility with MySQL 5.5 or earlier is a concern. This will prevent ALTER TABLE from moving InnoDB tables from the system tablespace to individual .ibd files.

    innodb_file_per_table is dynamic and can be set ON or OFF using SET GLOBAL. You can also set this option in the MySQL configuration file (my.cnf or my.ini) but this requires shutting down and restarting the server.

    Dynamically changing the value requires the SYSTEM_VARIABLES_ADMIN or SUPER privilege and immediately affects the operation of all connections.

    The innodb_file_per-table setting does not affect the creation of InnoDB temporary tables. All InnoDB temporary tables are created in the shared temporary tablespace.

  • innodb_fill_factor

    Command-Line Format--innodb-fill-factor=#
    System VariableNameinnodb_fill_factor
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default100
    Minimum10
    Maximum100

    InnoDB performs a bulk load when creating or rebuilding indexes. This method of index creation is known as a sorted index build.

    innodb_fill_factor defines the percentage of space on each B-tree page that is filled during a sorted index build, with the remaining space reserved for future index growth. For example, setting innodb_fill_factor to 80 reserves 20 percent of the space on each B-tree page for future index growth. Actual percentages may vary. The innodb_fill_factor setting is interpreted as a hint rather than a hard limit.

    An innodb_fill_factor setting of 100 leaves 1/16 of the space in clustered index pages free for future index growth.

    innodb_fill_factor applies to both B-tree leaf and non-leaf pages. It does not apply to external pages used for TEXT or BLOB entries.

    For more information, see Section 15.8.2.3, “Sorted Index Builds”.

  • innodb_flush_log_at_timeout

    System VariableNameinnodb_flush_log_at_timeout
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default1
    Minimum1
    Maximum2700

    Write and flush the logs every N seconds. innodb_flush_log_at_timeout allows the timeout period between flushes to be increased in order to reduce flushing and avoid impacting performance of binary log group commit. The default setting for innodb_flush_log_at_timeout is once per second.

  • innodb_flush_log_at_trx_commit

    Command-Line Format--innodb-flush-log-at-trx-commit[=#]
    System VariableNameinnodb_flush_log_at_trx_commit
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeenumeration
    Default1
    Valid Values0
    1
    2

    Controls 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 InnoDB log 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 InnoDB log 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 InnoDB log 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 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 log flushing frequency is controlled by innodb_flush_log_at_timeout, which allows you to set log flushing frequency to N seconds (where N is 1 ... 2700, with a default value of 1). However, any mysqld process crash can erase up to N seconds of transactions.

    • DDL changes and other internal InnoDB activities flush the InnoDB log independently of the innodb_flush_log_at_trx_commit setting. DDL logs are always flushed at transaction commit.

    • InnoDB crash recovery works regardless of the innodb_flush_log_at_trx_commit setting. Transactions are either applied entirely or erased entirely.

    For durability and consistency in a replication setup that uses InnoDB with transactions:

    • If binary logging is enabled, set sync_binlog=1.

    • Always set innodb_flush_log_at_trx_commit=1.

    Caution

    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. In this case, the durability of transactions is not guaranteed even with the setting 1, and in the worst case, a power outage can corrupt InnoDB data. 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 to disable the caching of disk writes in hardware caches.

  • innodb_flush_method

    Command-Line Format--innodb-flush-method=name
    System VariableNameinnodb_flush_method
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted Values (Unix)Typestring
    Defaultfsync
    Valid Valuesfsync
    O_DSYNC
    littlesync
    nosync
    O_DIRECT
    O_DIRECT_NO_FSYNC
    Permitted Values (Windows)Typestring
    Defaultunbuffered
    Valid Valuesunbuffered
    normal

    Defines the method used to flush data to InnoDB data files and log files, which can affect I/O throughput.

    On Unix-like systems, the default value is fsync. On Windows, the default value is unbuffered.

    Note

    In MySQL 8.0, innodb_flush_method options may be specified numerically.

    The innodb_flush_method options for Unix-like systems include:

    • fsync or 0: InnoDB uses the fsync() system call to flush both the data and log files. fsync is the default setting.

    • O_DSYNC or 1: InnoDB uses O_SYNC to open and flush the log files, and fsync() to flush the data files. InnoDB does not use O_DSYNC directly because there have been problems with it on many varieties of Unix.

    • littlesync or 2: This option is used for internal performance testing and is currently unsupported. Use at your own risk.

    • nosync or 3: This option is used for internal performance testing and is currently unsupported. Use at your own risk.

    • O_DIRECT or 4: InnoDB uses O_DIRECT (or directio() on Solaris) to open the data files, and uses fsync() to flush both the data and log files. This option is available on some GNU/Linux versions, FreeBSD, and Solaris.

    • O_DIRECT_NO_FSYNC or 5: InnoDB uses O_DIRECT during flushing I/O, but skips the fsync() system call afterward. This setting is suitable for some types of file systems but not others. For example, it is not suitable for XFS. If you are not sure whether the file system you use requires an fsync(), for example to preserve all file metadata, use O_DIRECT instead.

    The innodb_flush_method options for Windows systems include:

    • unbuffered or 0: InnoDB uses simulated asynchronous I/O and non-buffered I/O.

    • normal or 1: InnoDB uses simulated asynchronous I/O and buffered I/O.

    How each setting 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_fsyncs status variable to see the overall number of fsync() 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_DIRECT can help to avoid double buffering between the InnoDB buffer pool and the operating system file system cache. On some systems where InnoDB data and log files are located on a SAN, the default value or O_DSYNC might be faster for a read-heavy workload with mostly SELECT statements. Always test this parameter with hardware and workload that reflect your production environment. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

    If innodb_dedicated_server is enabled, the innodb_flush_method value is automatically configured if it is not explicitly defined. For more information, see Section 15.6.13, “Enabling Automatic Configuration for a Dedicated MySQL Server”.

  • innodb_flush_neighbors

    Command-Line Format--innodb-flush-neighbors
    System VariableNameinnodb_flush_neighbors
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (<= 8.0.2)Typeenumeration
    Default1
    Valid Values0
    1
    2
    Permitted Values (>= 8.0.3)Typeenumeration
    Default0
    Valid Values0
    1
    2

    Specifies whether flushing a page from the InnoDB buffer pool also flushes other dirty pages in the same extent.

    • A setting of 0 turns innodb_flush_neighbors off and no other dirty pages are flushed from the buffer pool.

    • A setting of 1 flushes contiguous dirty pages in the same extent from the buffer pool.

    • A setting of 2 flushes dirty pages in the same extent from the buffer pool.

    When the table data is stored on a traditional HDD storage device, flushing such neighbor pages in one operation reduces I/O overhead (primarily for disk seek operations) compared to flushing individual pages at different times. For table data stored on SSD, seek time is not a significant factor and you can set this option to 0 to spread out write operations. For related information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”.

  • innodb_flush_sync

    Command-Line Format--innodb-flush-sync=#
    System VariableNameinnodb_flush_sync
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    The innodb_flush_sync parameter, which is enabled by default, causes the innodb_io_capacity setting to be ignored for bursts of I/O activity that occur at checkpoints. To adhere to the limit on InnoDB background I/O activity defined by the innodb_io_capacity setting, disable innodb_flush_sync.

    For related information, see Section 15.6.8, “Configuring the InnoDB Master Thread I/O Rate”.

  • innodb_flushing_avg_loops

    Command-Line Format--innodb-flushing-avg-loops=#
    System VariableNameinnodb_flushing_avg_loops
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default30
    Minimum1
    Maximum1000

    Number of iterations for which InnoDB keeps the previously calculated snapshot of the flushing state, controlling how quickly adaptive flushing responds to changing workloads. Increasing the value makes the rate of flush operations change smoothly and gradually as the workload changes. Decreasing the value makes adaptive flushing adjust quickly to workload changes, which can cause spikes in flushing activity if the workload increases and decreases suddenly.

    For related information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”.

  • innodb_force_load_corrupted

    Command-Line Format--innodb-force-load-corrupted
    System VariableNameinnodb_force_load_corrupted
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Permits InnoDB to load tables at startup that are marked as corrupted. Use only during troubleshooting, to recover data that is otherwise inaccessible. When troubleshooting is complete, disable this setting and restart the server.

  • innodb_force_recovery

    Command-Line Format--innodb-force-recovery=#
    System VariableNameinnodb_force_recovery
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0
    Maximum6

    The 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 15.20.2, “Forcing InnoDB Recovery”.

    Warning

    Only set this variable to a value greater than 0 in an emergency situation so that you can start InnoDB and dump your tables. As a safety measure, InnoDB prevents INSERT, UPDATE, or DELETE operations when innodb_force_recovery is greater than 0. An innodb_force_recovery setting of 4 or greater places InnoDB into read-only mode.

    These restrictions may cause replication administration commands to fail with an error, as replication stores the slave status logs in InnoDB tables.

  • innodb_ft_aux_table

    Command-Line Format--innodb-ft-aux-table=#
    System VariableNameinnodb_ft_aux_table
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypestring

    Specifies the qualified name of an InnoDB table containing a FULLTEXT index. This variable is intended for diagnostic purposes.

    After you set this variable to a name in the format db_name/table_name, the INFORMATION_SCHEMA tables INNODB_FT_INDEX_TABLE, INNODB_FT_INDEX_CACHE, INNODB_FT_CONFIG, INNODB_FT_DELETED, and INNODB_FT_BEING_DELETED show information about the search index for the specified table.

    For more information, see Section 15.14.4, “InnoDB INFORMATION_SCHEMA FULLTEXT Index Tables”.

  • innodb_ft_cache_size

    Command-Line Format--innodb-ft-cache-size=#
    System VariableNameinnodb_ft_cache_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default8000000
    Minimum1600000
    Maximum80000000

    The memory allocated, in bytes, for the InnoDB FULLTEXT search index cache, which holds a parsed document in memory while creating an InnoDB FULLTEXT index. Index inserts and updates are only committed to disk when the innodb_ft_cache_size size limit is reached. innodb_ft_cache_size defines the cache size on a per table basis. To set a global limit for all tables, see innodb_ft_total_cache_size.

    For more information, see InnoDB Full-Text Index Cache.

  • innodb_ft_enable_diag_print

    Command-Line Format--innodb-ft-enable-diag-print=#
    System VariableNameinnodb_ft_enable_diag_print
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Whether to enable additional full-text search (FTS) diagnostic output. This option is primarily intended for advanced FTS debugging and will not be of interest to most users. Output is printed to the error log and includes information such as:

    • FTS index sync progress (when the FTS cache limit is reached). For example:

      FTS SYNC for table test, deleted count: 100 size: 10000 bytes
      SYNC words: 100
    • FTS optimize progress. For example:

      FTS start optimize test
      FTS_OPTIMIZE: optimize "mysql"
      FTS_OPTIMIZE: processed "mysql"
    • FTS index build progress. For example:

      Number of doc processed: 1000
    • For FTS queries, the query parsing tree, word weight, query processing time, and memory usage are printed. For example:

      FTS Search Processing time: 1 secs: 100 millisec: row(s) 10000
      Full Search Memory: 245666 (bytes),  Row: 10000
  • innodb_ft_enable_stopword

    Command-Line Format--innodb-ft-enable-stopword=#
    System VariableNameinnodb_ft_enable_stopword
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Specifies that a set of stopwords is associated with an InnoDB FULLTEXT index at the time the index is created. If the innodb_ft_user_stopword_table option is set, the stopwords are taken from that table. Else, if the innodb_ft_server_stopword_table option is set, the stopwords are taken from that table. Otherwise, a built-in set of default stopwords is used.

    For more information, see Section 12.9.4, “Full-Text Stopwords”.

  • innodb_ft_max_token_size

    Command-Line Format--innodb-ft-max-token-size=#
    System VariableNameinnodb_ft_max_token_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default84
    Minimum10
    Maximum84
    Permitted ValuesTypeinteger
    Default84
    Minimum10
    Maximum84

    Maximum character length of words that are stored in an InnoDB FULLTEXT index. Setting a limit on this value reduces the size of the index, thus speeding up queries, by omitting long keywords or arbitrary collections of letters that are not real words and are not likely to be search terms.

    For more information, see Section 12.9.6, “Fine-Tuning MySQL Full-Text Search”.

  • innodb_ft_min_token_size

    Command-Line Format--innodb-ft-min-token-size=#
    System VariableNameinnodb_ft_min_token_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default3
    Minimum0
    Maximum16

    Minimum length of words that are stored in an InnoDB FULLTEXT index. Increasing this value reduces the size of the index, thus speeding up queries, by omitting common words that are unlikely to be significant in a search context, such as the English words a and to. For content using a CJK (Chinese, Japanese, Korean) character set, specify a value of 1.

    For more information, see Section 12.9.6, “Fine-Tuning MySQL Full-Text Search”.

  • innodb_ft_num_word_optimize

    Command-Line Format--innodb-ft-num-word-optimize=#
    System VariableNameinnodb_ft_num_word_optimize
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default2000

    Number of words to process during each OPTIMIZE TABLE operation on an InnoDB FULLTEXT index. Because a bulk insert or update operation to a table containing a full-text search index could require substantial index maintenance to incorporate all changes, you might do a series of OPTIMIZE TABLE statements, each picking up where the last left off.

    For more information, see Section 12.9.6, “Fine-Tuning MySQL Full-Text Search”.

  • innodb_ft_result_cache_limit

    Command-Line Format--innodb-ft-result-cache-limit=#
    System VariableNameinnodb_ft_result_cache_limit
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default2000000000
    Minimum1000000
    Maximum2**32-1

    The InnoDB full-text search query result cache limit (defined in bytes) per full-text search query or per thread. Intermediate and final InnoDB full-text search query results are handled in memory. Use innodb_ft_result_cache_limit to place a size limit on the full-text search query result cache to avoid excessive memory consumption in case of very large InnoDB full-text search query results (millions or hundreds of millions of rows, for example). Memory is allocated as required when a full-text search query is processed. If the result cache size limit is reached, an error is returned indicating that the query exceeds the maximum allowed memory.

    The maximum value of innodb_ft_result_cache_limit for all platform types and bit sizes is 2**32-1.

  • innodb_ft_server_stopword_table

    Command-Line Format--innodb-ft-server-stopword-table=db_name/table_name
    System VariableNameinnodb_ft_server_stopword_table
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypestring
    DefaultNULL

    This option is used to specify your own InnoDB FULLTEXT index stopword list for all InnoDB tables. To configure your own stopword list for a specific InnoDB table, use innodb_ft_user_stopword_table.

    Set innodb_ft_server_stopword_table to the name of the table containing a list of stopwords, in the format db_name/table_name.

    The stopword table must exist before you configure innodb_ft_server_stopword_table. innodb_ft_enable_stopword must be enabled and innodb_ft_server_stopword_table option must be configured before you create the FULLTEXT index.

    The stopword table must be an InnoDB table, containing a single VARCHAR column named value.

    For more information, see Section 12.9.4, “Full-Text Stopwords”.

  • innodb_ft_sort_pll_degree

    Command-Line Format--innodb-ft-sort-pll-degree=#
    System VariableNameinnodb_ft_sort_pll_degree
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default2
    Minimum1
    Maximum32

    Number of threads used in parallel to index and tokenize text in an InnoDB FULLTEXT index when building a search index.

    For related information, see Section 15.8.2.4, “InnoDB FULLTEXT Indexes”, and innodb_sort_buffer_size.

  • innodb_ft_total_cache_size

    Command-Line Format--innodb-ft-total-cache-size=#
    System VariableNameinnodb_ft_total_cache_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default640000000
    Minimum32000000
    Maximum1600000000

    The total memory allocated, in bytes, for the InnoDB full-text search index cache for all tables. Creating numerous tables, each with a FULLTEXT search index, could consume a significant portion of available memory. innodb_ft_total_cache_size defines a global memory limit for all full-text search indexes to help avoid excessive memory consumption. If the global limit is reached by an index operation, a forced sync is triggered.

    For more information, see InnoDB Full-Text Index Cache.

  • innodb_ft_user_stopword_table

    Command-Line Format--innodb-ft-user-stopword-table=db_name/table_name
    System VariableNameinnodb_ft_user_stopword_table
    ScopeGlobal, Session
    DynamicYes
    HintableNo
    Permitted ValuesTypestring
    DefaultNULL

    This option is used to specify your own InnoDB FULLTEXT index stopword list on a specific table. To configure your own stopword list for all InnoDB tables, use innodb_ft_server_stopword_table.

    Set innodb_ft_user_stopword_table to the name of the table containing a list of stopwords, in the format db_name/table_name.

    The stopword table must exist before you configure innodb_ft_user_stopword_table. innodb_ft_enable_stopword must be enabled and innodb_ft_user_stopword_table must be configured before you create the FULLTEXT index.

    The stopword table must be an InnoDB table, containing a single VARCHAR column named value.

    For more information, see Section 12.9.4, “Full-Text Stopwords”.

  • innodb_io_capacity

    Command-Line Format--innodb-io-capacity=#
    System VariableNameinnodb_io_capacity
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default200
    Minimum100
    Maximum2**32-1
    Permitted Values (64-bit platforms)Typeinteger
    Default200
    Minimum100
    Maximum2**64-1

    The innodb_io_capacity parameter sets an upper limit on the number of I/O operations performed per second by InnoDB background tasks, such as flushing pages from the buffer pool and merging data from the change buffer.

    The innodb_io_capacity limit 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_capacity should 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 InnoDB I/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 100, which represents an estimated proportion of the I/O operations per second (IOPS) available to older-generation disk drives that can 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_capacity to any number 100 or greater to a maximum defined by innodb_io_capacity_max. innodb_io_capacity can be set in the MySQL option file (my.cnf or my.ini) or changed dynamically using a SET GLOBAL statement, which requires the SYSTEM_VARIABLES_ADMIN or SUPER privilege.

    The innodb_flush_sync configuration option causes the innodb_io_capacity setting to be ignored during bursts of I/O activity that occur at checkpoints. innodb_flush_sync is enabled by default.

    See Section 15.6.8, “Configuring the InnoDB Master Thread I/O Rate” for more information. For general information about InnoDB I/O performance, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_io_capacity_max

    Command-Line Format--innodb-io-capacity-max=#
    System VariableNameinnodb_io_capacity_max
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (32-bit platforms)Typeinteger
    Defaultsee description
    Minimum100
    Maximum2**32-1
    Permitted Values (Unix, 64-bit platforms)Typeinteger
    Defaultsee description
    Minimum100
    Maximum2**64-1
    Permitted Values (Windows, 64-bit platforms)Typeinteger
    Defaultsee description
    Minimum100
    Maximum2**32-1

    If flushing activity falls behind, InnoDB can flush more aggressively than the limit imposed by innodb_io_capacity. innodb_io_capacity_max defines an upper limit the number of I/O operations performed per second by InnoDB background tasks in such situations.

    The innodb_io_capacity_max setting is a total limit for all buffer pool instances.

    If you specify an innodb_io_capacity setting at startup but do not specify a value for innodb_io_capacity_max, innodb_io_capacity_max defaults to twice the value of innodb_io_capacity, with a minimum value of 2000.

    When configuring innodb_io_capacity_max, twice the innodb_io_capacity is often a good starting point. The default value of 2000 is intended for workloads that use a solid-state disk (SSD) or more than one regular disk drive. A setting of 2000 is likely too high for workloads that do not use SSD or multiple disk drives, and could allow too much flushing. For a single regular disk drive, a setting between 200 and 400 is recommended. For a high-end, bus-attached SSD, consider a higher setting such as 2500. As with the innodb_io_capacity setting, keep the setting as low as practical, but not so low that InnoDB cannot sufficiently extend beyond the innodb_io_capacity limit, if necessary.

    Consider write workload when tuning innodb_io_capacity_max. Systems with large write workloads may benefit from a higher setting. A lower setting may be sufficient for systems with a small write workload.

    innodb_io_capacity_max cannot be set to a value lower than the innodb_io_capacity value.

    Setting innodb_io_capacity_max to DEFAULT using a SET statement (SET GLOBAL innodb_io_capacity_max=DEFAULT) sets innodb_io_capacity_max to the maximum value.

    For related information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”.

  • innodb_limit_optimistic_insert_debug

    Command-Line Format--innodb-limit-optimistic-insert-debug=#
    System VariableNameinnodb_limit_optimistic_insert_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0
    Maximum2**32-1

    Limits 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_DEBUG CMake option.

  • innodb_lock_wait_timeout

    Command-Line Format--innodb-lock-wait-timeout=#
    System VariableNameinnodb_lock_wait_timeout
    ScopeGlobal, Session
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default50
    Minimum1
    Maximum1073741824

    The length of time in seconds an InnoDB transaction waits for a row lock before giving up. The default value is 50 seconds. A transaction that tries to access a row that is locked by another InnoDB transaction waits at most this many seconds for write access to the row before issuing the following error:

    ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction

    When a lock wait timeout occurs, the current statement is rolled back (not the entire transaction). To have the entire transaction roll back, start the server with the --innodb_rollback_on_timeout option. See also Section 15.20.4, “InnoDB Error Handling”.

    You might decrease this value for highly interactive applications or OLTP systems, to display user feedback quickly or put the update into a queue for processing later. You might increase this value for long-running back-end operations, such as a transform step in a data warehouse that waits for other large insert or update operations to finish.

    innodb_lock_wait_timeout applies to InnoDB row locks. A MySQL table lock does not happen inside InnoDB and this timeout does not apply to waits for table locks.

    The lock wait timeout value does not apply to deadlocks when innodb_deadlock_detect is enabled (the default) because InnoDB detects deadlocks immediately and rolls back one of the deadlocked transactions. When innodb_deadlock_detect is disabled, InnoDB relies on innodb_lock_wait_timeout for transaction rollback when a deadlock occurs. See Section 15.5.5.2, “Deadlock Detection and Rollback”.

    innodb_lock_wait_timeout can be set at runtime with the SET GLOBAL or SET SESSION statement. Changing the GLOBAL setting requires the SYSTEM_VARIABLES_ADMIN or SUPER privilege and affects the operation of all clients that subsequently connect. Any client can change the SESSION setting for innodb_lock_wait_timeout, which affects only that client.

  • innodb_log_buffer_size

    Command-Line Format--innodb-log-buffer-size=#
    System VariableNameinnodb_log_buffer_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default16777216
    Minimum1048576
    Maximum4294967295

    The size in bytes of the buffer that InnoDB uses to write to the log files on disk. The default is 16MB. A large log buffer enables large transactions to run without the 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 related information, see InnoDB Memory Configuration, and Section 8.5.4, “Optimizing InnoDB Redo Logging”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_log_checksums

    Command-Line Format--innodb-log-checksums=#
    System VariableNameinnodb_log_checksums
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Enables or disables checksums for redo log pages.

    innodb_log_checksums=ON enables the CRC-32C checksum algorithm for redo log pages. When innodb_log_checksums is disabled, the contents of the redo log page checksum field are ignored.

    Checksums on the redo log header page and redo log checkpoint pages are never disabled.

  • innodb_log_compressed_pages

    Command-Line Format--innodb-log-compressed-pages=#
    System VariableNameinnodb_log_compressed_pages
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Specifies whether images of re-compressed pages are written to the redo log. Re-compression may occur when changes are made to compressed data.

    innodb_log_compressed_pages is enabled by default to prevent corruption that could occur if a different version of the zlib compression algorithm is used during recovery. If you are certain that the zlib version will not change, you can disable innodb_log_compressed_pages to reduce redo log generation for workloads that modify compressed data.

    To measure the effect of enabling or disabling innodb_log_compressed_pages, compare redo log generation for both settings under the same workload. Options for measuring redo log generation include observing the Log sequence number (LSN) in the LOG section of SHOW ENGINE INNODB STATUS output, or monitoring Innodb_os_log_written status for the number of bytes written to the redo log files.

    For related information, see Section 15.9.1.6, “Compression for OLTP Workloads”.

  • innodb_log_file_size

    Command-Line Format--innodb-log-file-size=#
    System VariableNameinnodb_log_file_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default50331648
    Minimum4194304
    Maximum512GB / innodb_log_files_in_group

    The 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 512GB. A pair of 255 GB log files, for example, approaches the limit but does not exceed it. The default value is 48MB.

    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 required 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.

    The minimum innodb_log_file_size is 4MB.

    For related information, see InnoDB Log File Configuration. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

    If innodb_dedicated_server is enabled, the innodb_log_file_size value is automatically configured if it is not explicitly defined. For more information, see Section 15.6.13, “Enabling Automatic Configuration for a Dedicated MySQL Server”.

  • innodb_log_files_in_group

    Command-Line Format--innodb-log-files-in-group=#
    System VariableNameinnodb_log_files_in_group
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default2
    Minimum2
    Maximum100

    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. The location of the files is specified by innodb_log_group_home_dir. The combined size of log files (innodb_log_file_size * innodb_log_files_in_group) can be up to 512GB.

    For related information, see InnoDB Log File Configuration.

  • innodb_log_group_home_dir

    Command-Line Format--innodb-log-group-home-dir=dir_name
    System VariableNameinnodb_log_group_home_dir
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypedirectory name

    The directory path to the InnoDB redo log files, whose number is specified by innodb_log_files_in_group. If you do not specify any InnoDB log variables, the default is to create two files named ib_logfile0 and ib_logfile1 in the MySQL data directory. Log file size is given by the innodb_log_file_size system variable.

    For related information, see InnoDB Log File Configuration.

  • innodb_log_write_ahead_size

    Command-Line Format--innodb-log-write-ahead-size=#
    System VariableNameinnodb_log_write_ahead_size
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default8192
    Minimum512 (log file block size)
    MaximumEqual to innodb_page_size

    The write-ahead block size for the redo log, in bytes. To avoid read-on-write, set innodb_log_write_ahead_size to match the operating system or file system cache block size. Read-on-write occurs when redo log blocks are not entirely cached to the operating system or file system due to a mismatch between write-ahead block size for redo logs and operating system or file system cache block size.

    Valid values for innodb_log_write_ahead_size are multiples of the InnoDB log file block size (2^n). The minimum value is the InnoDB log file block size (512). Write-ahead does not occur when the minimum value is specified. The maximum value is equal to innodb_page_size. If you specify a value for innodb_log_write_ahead_size that is larger than the innodb_page_size value, the innodb_log_write_ahead_size value is truncated to the innodb_page_size value.

    Setting the innodb_log_write_ahead_size value too low in relation to the operating system or file system cache block size results in read-on-write. Setting the value too high may have a slight impact on fsync performance for log file writes due to several blocks being written at once.

  • innodb_lru_scan_depth

    Command-Line Format--innodb-lru-scan-depth=#
    System VariableNameinnodb_lru_scan_depth
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default1024
    Minimum100
    Maximum2**32-1
    Permitted Values (64-bit platforms)Typeinteger
    Default1024
    Minimum100
    Maximum2**64-1

    A parameter that influences the algorithms and heuristics for the flush operation for the InnoDB buffer pool. Primarily of interest to performance experts tuning I/O-intensive workloads. It specifies, per buffer pool instance, how far down the buffer pool LRU page list the page cleaner thread scans looking for dirty pages to flush. This is a background operation performed once per second.

    A setting smaller than the default is generally suitable for most workloads. A value that is much higher than necessary may impact performance. Only consider increasing the value if you have spare I/O capacity under a typical workload. Conversely, if a write-intensive workload saturates your I/O capacity, decrease the value, especially in the case of a large buffer pool.

    When tuning innodb_lru_scan_depth, start with a low value and configure the setting upward with the goal of rarely seeing zero free pages. Also, consider adjusting innodb_lru_scan_depth when changing the number of buffer pool instances, since innodb_lru_scan_depth * innodb_buffer_pool_instances defines the amount of work performed by the page cleaner thread each second.

    For related information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_max_dirty_pages_pct

    Command-Line Format--innodb-max-dirty-pages-pct=#
    System VariableNameinnodb_max_dirty_pages_pct
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (<= 8.0.2)Typenumeric
    Default75
    Minimum0
    Maximum99.99
    Permitted Values (>= 8.0.3)Typenumeric
    Default90
    Minimum0
    Maximum99.99

    InnoDB tries to flush data from the buffer pool so that the percentage of dirty pages does not exceed this value.

    The innodb_max_dirty_pages_pct setting establishes a target for flushing activity. It does not affect the rate of flushing. For information about managing the rate of flushing, see Section 15.6.3.6, “Configuring InnoDB Buffer Pool Flushing”.

    For related information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_max_dirty_pages_pct_lwm

    Command-Line Format--innodb-max-dirty-pages-pct-lwm=#
    System VariableNameinnodb_max_dirty_pages_pct_lwm
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (<= 8.0.2)Typenumeric
    Default0
    Minimum0
    Maximum99.99
    Permitted Values (>= 8.0.3)Typenumeric
    Default10
    Minimum0
    Maximum99.99

    Defines a low water mark representing the percentage of dirty pages at which preflushing is enabled to control the dirty page ratio. A value of 0 disables the pre-flushing behavior entirely. For more information, see Section 15.6.3.7, “Fine-tuning InnoDB Buffer Pool Flushing”.

  • innodb_max_purge_lag

    Command-Line Format--innodb-max-purge-lag=#
    System VariableNameinnodb_max_purge_lag
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0
    Maximum4294967295

    Controls how to delay INSERT, UPDATE, and DELETE operations when purge operations are lagging (see Section 15.3, “InnoDB Multi-Versioning”). The unit value is microseconds. The default value is 0 (no delays).

    The InnoDB transaction system maintains a list of transactions that have index records delete-marked by UPDATE or DELETE operations. The length of the list represents the purge_lag value. When purge_lag exceeds innodb_max_purge_lag, INSERT, UPDATE, and DELETE operations are delayed.

    To prevent excessive delays in extreme situations where purge_lag becomes huge, you can limit the delay by setting the innodb_max_purge_lag_delay configuration option. The delay is computed at the beginning of a purge batch.

    A typical setting for a problematic workload might be 1 million, assuming that transactions are small, only 100 bytes in size, and it is permissible to have 100MB of unpurged InnoDB table rows.

    The lag value is displayed as the history list length in the TRANSACTIONS section of InnoDB Monitor output . For example, if the output includes the following lines, the lag value is 20:

    ------------
    TRANSACTIONS
    ------------
    Trx id counter 0 290328385
    Purge done for trx's n:o < 0 290315608 undo n:o < 0 17
    History list length 20

    For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_max_purge_lag_delay

    Command-Line Format--innodb-max-purge-lag-delay=#
    System VariableNameinnodb_max_purge_lag_delay
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0

    Specifies the maximum delay in microseconds for the delay imposed by the innodb_max_purge_lag configuration option. A non-zero value represents an upper limit on the delay period computed from the formula based on the value of innodb_max_purge_lag. The default of zero means that there is no upper limit imposed on the delay interval.

    For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_max_undo_log_size

    Command-Line Format--innodb-max-undo-log-size=#
    System VariableNameinnodb_max_undo_log_size
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default1073741824
    Minimum10485760
    Maximum2**64-1

    Defines a threshold size for undo tablespaces. If an undo tablespace exceeds the threshold, it can be marked for truncation when innodb_undo_log_truncate is enabled. The default value is 1073741824 bytes (1024 MiB).

    For more information, see Section 15.7.8, “Truncating Undo Tablespaces”.

  • innodb_merge_threshold_set_all_debug

    Command-Line Format--innodb-merge-threshold-set-all-debug=#
    System VariableNameinnodb_merge_threshold_set_all_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default50
    Minimum1
    Maximum50

    Defines a page-full percentage value for index pages that overrides the current MERGE_THRESHOLD setting for all indexes that are currently in the dictionary cache. This option is only available if debugging support is compiled in using the WITH_DEBUG CMake option. For related information, see Section 15.6.12, “Configuring the Merge Threshold for Index Pages”.

  • innodb_monitor_disable

    Command-Line Format--innodb-monitor-disable=[counter|module|pattern|all]
    System VariableNameinnodb_monitor_disable
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypestring

    Disables InnoDB metrics counters. Counter data may be queried using the INFORMATION_SCHEMA.INNODB_METRICS table. For usage information, see Section 15.14.6, “InnoDB INFORMATION_SCHEMA Metrics Table”.

    innodb_monitor_disable='latch' disables statistics collection for SHOW ENGINE INNODB MUTEX. For more information, see Section 13.7.6.15, “SHOW ENGINE Syntax”.

  • innodb_monitor_enable

    Command-Line Format--innodb-monitor-enable=[counter|module|pattern|all]
    System VariableNameinnodb_monitor_enable
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypestring

    Enables InnoDB metrics counters. Counter data may be queried using the INFORMATION_SCHEMA.INNODB_METRICS table. For usage information, see Section 15.14.6, “InnoDB INFORMATION_SCHEMA Metrics Table”.

    innodb_monitor_enable='latch' enables statistics collection for SHOW ENGINE INNODB MUTEX. For more information, see Section 13.7.6.15, “SHOW ENGINE Syntax”.

  • innodb_monitor_reset

    Command-Line Format--innodb-monitor-reset=[counter|module|pattern|all]
    System VariableNameinnodb_monitor_reset
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypestring

    Resets the count value for InnoDB metrics counters to zero. Counter data may be queried using the INFORMATION_SCHEMA.INNODB_METRICS table. For usage information, see Section 15.14.6, “InnoDB INFORMATION_SCHEMA Metrics Table”.

    innodb_monitor_reset='latch' resets statistics reported by SHOW ENGINE INNODB MUTEX. For more information, see Section 13.7.6.15, “SHOW ENGINE Syntax”.

  • innodb_monitor_reset_all

    Command-Line Format--innodb-monitor-reset-all=[counter|module|pattern|all]
    System VariableNameinnodb_monitor_reset_all
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypestring

    Resets all values (minimum, maximum, and so on) for InnoDB metrics counters. Counter data may be queried using the INFORMATION_SCHEMA.INNODB_METRICS table. For usage information, see Section 15.14.6, “InnoDB INFORMATION_SCHEMA Metrics Table”.

  • innodb_numa_interleave

    Command-Line Format--innodb-numa-interleave=#
    System VariableNameinnodb_numa_interleave
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enables the NUMA interleave memory policy for allocation of the InnoDB buffer pool. When innodb_numa_interleave is enabled, the NUMA memory policy is set to MPOL_INTERLEAVE for the mysqld process. After the InnoDB buffer pool is allocated, the NUMA memory policy is set back to MPOL_DEFAULT. For the innodb_numa_interleave option to be available, MySQL must be compiled on a NUMA-enabled Linux system.

    CMake sets the default WITH_NUMA value based on whether the current platform has NUMA support. For more information, see Section 2.8.4, “MySQL Source-Configuration Options”.

  • innodb_old_blocks_pct

    Command-Line Format--innodb-old-blocks-pct=#
    System VariableNameinnodb_old_blocks_pct
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default37
    Minimum5
    Maximum95

    Specifies the approximate percentage of the InnoDB buffer pool used for the old block sublist. The range of values is 5 to 95. The default value is 37 (that is, 3/8 of the pool). Often used in combination with innodb_old_blocks_time.

    For more information, see Section 15.6.3.4, “Making the Buffer Pool Scan Resistant”. For information about buffer pool management, the LRU algorithm, and eviction policies, see Section 15.6.3.1, “The InnoDB Buffer Pool”.

  • innodb_old_blocks_time

    Command-Line Format--innodb-old-blocks-time=#
    System VariableNameinnodb_old_blocks_time
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default1000
    Minimum0
    Maximum2**32-1

    Non-zero values protect against the buffer pool being filled 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 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 milliseconds 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.

    The default value is 1000.

    This configuration option is often used in combination with innodb_old_blocks_pct. For more information, see Section 15.6.3.4, “Making the Buffer Pool Scan Resistant”. For information about buffer pool management, the LRU algorithm, and eviction policies, see Section 15.6.3.1, “The InnoDB Buffer Pool”.

  • innodb_online_alter_log_max_size

    Command-Line Format--innodb-online-alter-log-max-size=#
    System VariableNameinnodb_online_alter_log_max_size
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default134217728
    Minimum65536
    Maximum2**64-1

    Specifies an upper limit in bytes on the size of the temporary log files used during online DDL operations for InnoDB tables. There is one such log file for each index being created or table being altered. This log file stores data inserted, updated, or deleted in the table during the DDL operation. The temporary log file is extended when needed by the value of innodb_sort_buffer_size, up to the maximum specified by innodb_online_alter_log_max_size. If a temporary log file exceeds the upper size limit, the ALTER TABLE operation fails and all uncommitted concurrent DML operations are rolled back. Thus, a large value for this option allows more DML to happen during an online DDL operation, but also extends the period of time at the end of the DDL operation when the table is locked to apply the data from the log.

  • innodb_open_files

    Command-Line Format--innodb-open-files=#
    System VariableNameinnodb_open_files
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default-1 (autosized)
    Minimum10
    Maximum4294967295

    This configuration option is only relevant if you use multiple InnoDB tablespaces. It specifies the maximum number of .ibd files that MySQL can keep open at one time. The minimum value is 10. The default value is 300 if innodb_file_per_table is not enabled, and the higher of 300 and table_open_cache otherwise.

    The file descriptors used for .ibd files are for InnoDB tables only. They are independent of those specified by the --open-files-limit server option, and do not affect the operation of the table cache. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_optimize_fulltext_only

    Command-Line Format--innodb-optimize-fulltext-only=#
    System VariableNameinnodb_optimize_fulltext_only
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Changes the way OPTIMIZE TABLE operates on InnoDB tables. Intended to be enabled temporarily, during maintenance operations for InnoDB tables with FULLTEXT indexes.

    By default, OPTIMIZE TABLE reorganizes data in the clustered index of the table. When this option is enabled, OPTIMIZE TABLE skips the reorganization of table data, and instead processes newly added, deleted, and updated token data for InnoDB FULLTEXT indexes. Fore more information, see Optimizing InnoDB Full-Text Indexes.

  • innodb_page_cleaners

    Command-Line Format--innodb-page-cleaners=#
    System VariableNameinnodb_page_cleaners
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default4
    Minimum1
    Maximum64

    The number of page cleaner threads that flush dirty pages from buffer pool instances. Page cleaner threads perform flush list and LRU flushing. When there are multiple page cleaner threads, buffer pool flushing tasks for each buffer pool instance are dispatched to idle page cleaner threads. The innodb_page_cleaners default value is 4. If the number of page cleaner threads exceeds the number of buffer pool instances, innodb_page_cleaners is automatically set to the same value as innodb_buffer_pool_instances.

    If your workload is write-IO bound when flushing dirty pages from buffer pool instances to data files, and if your system hardware has available capacity, increasing the number of page cleaner threads may help improve write-IO throughput.

    Multi-threaded page cleaner support extends to shutdown and recovery phases.

    The setpriority() system call is used on Linux platforms where it is supported, and where the mysqld execution user is authorized to give page_cleaner threads priority over other MySQL and InnoDB threads to help page flushing keep pace with the current workload. setpriority() support is indicated by this InnoDB startup message:

    [Note] InnoDB: If the mysqld execution user is authorized, page cleaner
    thread priority can be changed. See the man page of setpriority().

    For systems where server startup and shutdown is not managed by systemd, mysqld execution user authorization can be configured in /etc/security/limits.conf. For example, if mysqld is run under the mysql user, you can authorize the mysql user by adding these lines to /etc/security/limits.conf:

    mysql              hard    nice       -20
    mysql              soft    nice       -20

    For systemd managed systems, the same can be achieved by specifying LimitNICE=-20 in a localized systemd configuration file. For example, create a file named override.conf in /etc/systemd/system/mysqld.service.d/override.conf and add this entry:

    [Service]
    LimitNICE=-20

    After creating or changing override.conf, reload the systemd configuration, then tell systemd to restart the MySQL service:

    systemctl daemon-reload
    systemctl restart mysqld  # RPM platforms
    systemctl restart mysql   # Debian platforms

    For more information about using a localized systemd configuration file, see Configuring systemd for MySQL.

    After authorizing the mysqld execution user, use the cat command to verify the configured Nice limits for the mysqld process:

    shell> cat /proc/mysqld_pid/limits | grep nice
    Max nice priority         18446744073709551596 18446744073709551596
  • innodb_page_size

    Command-Line Format--innodb-page-size=#k
    System VariableNameinnodb_page_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeenumeration
    Default16384
    Valid Values4k
    8k
    16k
    32k
    64k
    4096
    8192
    16384
    32768
    65536

    Specifies the page size for all InnoDB tablespaces in a MySQL instance. You can specify page size using the values 64k, 32k, 16k (the default), 8k, or 4k. Alternatively, you can specify page size in bytes (65536, 32768, 16384, 8192, 4096).

    innodb_page_size can only be configured prior to initializing the MySQL instance and cannot be changed afterward. If no value is specified, the instance is initialized using the default page size. See Section 15.6.1, “InnoDB Startup Configuration”.

    For both 32k and 64k page sizes, the maximum row length is approximately 16000 bytes. ROW_FORMAT=COMPRESSED is not supported when innodb_page_size is set to 32KB or 64KB. For innodb_page_size=32k, extent size is 2MB. For innodb_page_size=64k, extent size is 4MB. innodb_log_buffer_size should be set to at least 16M (the default) when using 32k or 64k page sizes.

    The default 16KB page size or larger is appropriate for a wide range of workloads, particularly for queries involving table scans and DML operations involving bulk updates. Smaller page sizes might be more efficient for OLTP workloads involving many small writes, where contention can be an issue when single pages contain many rows. Smaller pages might also be efficient with SSD storage devices, which typically use small block sizes. Keeping the InnoDB page size close to the storage device block size minimizes the amount of unchanged data that is rewritten to disk.

    The minimum file size for the first system tablespace data file (ibdata1) differs depending on the innodb_page_size value. See the innodb_data_file_path option description for more information.

    For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_print_all_deadlocks

    Command-Line Format--innodb-print-all-deadlocks=#
    System VariableNameinnodb_print_all_deadlocks
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    When this option is enabled, information about all deadlocks in InnoDB user transactions is recorded in the mysqld error log. Otherwise, you see information about only the last deadlock, using the SHOW ENGINE INNODB STATUS command. An occasional InnoDB deadlock is not necessarily an issue, because InnoDB detects the condition immediately and rolls back one of the transactions automatically. You might use this option to troubleshoot why deadlocks are occurring if an application does not have appropriate error-handling logic to detect the rollback and retry its operation. A large number of deadlocks might indicate the need to restructure transactions that issue DML or SELECT ... FOR UPDATE statements for multiple tables, so that each transaction accesses the tables in the same order, thus avoiding the deadlock condition.

    For related information, see Section 15.5.5, “Deadlocks in InnoDB”.

  • innodb_print_ddl_logs

    Introduced8.0.3
    Command-Line Format--innodb-print-ddl-logs=#
    System VariableNameinnodb_print_ddl_logs
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enabling this option causes MySQL to write DDL logs to stderr. For more information, see Viewing DDL Logs.

  • innodb_purge_batch_size

    Command-Line Format--innodb-purge-batch-size=#
    System VariableNameinnodb_purge_batch_size
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default300
    Minimum1
    Maximum5000

    Defines the number of undo log pages that purge parses and processes in one batch from the history list. In a multi-threaded purge configuration, the coordinator purge thread divides innodb_purge_batch_size by innodb_purge_threads and assigns that number of pages to each purge thread. The innodb_purge_batch_size option also defines the number of undo log pages that purge frees after every 128 iterations through the undo logs.

    The innodb_purge_batch_size option is intended for advanced performance tuning in combination with the innodb_purge_threads setting. Most MySQL users need not change innodb_purge_batch_size from its default value.

    For related information, see Section 15.6.10, “Configuring InnoDB Purge Scheduling”.

  • innodb_purge_threads

    Command-Line Format--innodb-purge-threads=#
    System VariableNameinnodb_purge_threads
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default4
    Minimum1
    Maximum32

    The number of background threads devoted to the InnoDB purge operation. A minimum value of 1 signifies that the purge operation is always performed by a background thread, never as part of the master thread. Running the purge operation in one or more background threads helps reduce internal contention within InnoDB, improving scalability. Increasing the value to greater than 1 creates that many separate purge threads, which can improve efficiency on systems where DML operations are performed on multiple tables. The maximum is 32.

    For related information, see Section 15.6.10, “Configuring InnoDB Purge Scheduling”.

  • innodb_purge_rseg_truncate_frequency

    Command-Line Format--innodb-purge-rseg-truncate-frequency=#
    System VariableNameinnodb_purge_rseg_truncate_frequency
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default128
    Minimum1
    Maximum128

    Defines the frequency with which the purge system frees rollback segments in terms of the number of times that purge is invoked. An undo tablespace cannot be truncated until its rollback segments are freed. Normally, the purge system frees rollback segments once every 128 times that purge is invoked. The default value is 128. Reducing this value increases the frequency with which the purge thread frees rollback segments.

    innodb_purge_rseg_truncate_frequency is intended for use with innodb_undo_log_truncate. For more information, see Section 15.7.8, “Truncating Undo Tablespaces”.

  • innodb_random_read_ahead

    Command-Line Format--innodb-random-read-ahead=#
    System VariableNameinnodb_random_read_ahead
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enables the random read-ahead technique for optimizing InnoDB I/O.

    For details about performance considerations for different types of read-ahead requests, see Section 15.6.3.5, “Configuring InnoDB Buffer Pool Prefetching (Read-Ahead)”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_read_ahead_threshold

    Command-Line Format--innodb-read-ahead-threshold=#
    System VariableNameinnodb_read_ahead_threshold
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default56
    Minimum0
    Maximum64

    Controls the sensitivity of linear read-ahead that InnoDB uses to prefetch pages into the buffer pool. If InnoDB reads at least innodb_read_ahead_threshold pages sequentially from an extent (64 pages), it initiates an asynchronous read for the entire following extent. The permissible range of values is 0 to 64. A value of 0 disables read-ahead. For the default of 56, InnoDB must 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 the read-ahead mechanism, and how many of these pages are evicted from the buffer pool without ever being accessed, can be useful when fine-tuning the innodb_read_ahead_threshold setting. SHOW ENGINE INNODB STATUS output displays counter information from the Innodb_buffer_pool_read_ahead and Innodb_buffer_pool_read_ahead_evicted global status variables, which report 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. The status variables report global values since the last server restart.

    SHOW ENGINE INNODB STATUS also 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 of SHOW ENGINE INNODB STATUS and are displayed in the BUFFER POOL AND MEMORY section of the SHOW ENGINE INNODB STATUS output.

    For more information, see Section 15.6.3.5, “Configuring InnoDB Buffer Pool Prefetching (Read-Ahead)”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

  • innodb_read_io_threads

    Command-Line Format--innodb-read-io-threads=#
    System VariableNameinnodb_read_io_threads
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default4
    Minimum1
    Maximum64

    The number of I/O threads for read operations in InnoDB. Its counterpart for write threads is innodb_write_io_threads. For more information, see Section 15.6.6, “Configuring the Number of Background InnoDB I/O Threads”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

    Note

    On Linux systems, running multiple MySQL servers (typically more than 12) with default settings for innodb_read_io_threads, innodb_write_io_threads, and the Linux aio-max-nr setting can exceed system limits. Ideally, increase the aio-max-nr setting; as a workaround, you might reduce the settings for one or both of the MySQL configuration options.

  • innodb_read_only

    Command-Line Format--innodb-read-only=#
    System VariableNameinnodb_read_only
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Starts InnoDB in read-only mode. For distributing database applications or data sets on read-only media. Can also be used in data warehouses to share the same data directory between multiple instances. For more information, see Section 15.6.2, “Configuring InnoDB for Read-Only Operation”.

    Previously, enabling the innodb_read_only system variable prevented creating and dropping tables only for the InnoDB storage engine. As of MySQL 8.0, enabling innodb_read_only prevents these operations for all storage engines. Table creation and drop operations for any storage engine modify data dictionary tables in the mysql system database, but those tables use the InnoDB storage engine and cannot be modified when innodb_read_only is enabled. The same principle applies to other table operations that require modifying data dictionary tables. Examples:

    In addition, other tables in the mysql system database use the InnoDB storage engine in MySQL 8.0. Making those tables read only results in restrictions on operations that modify them. Examples:

  • innodb_redo_log_encrypt

    Introduced8.0.1
    Command-Line Format--innodb-redo-log-encrypt=#
    System VariableNameinnodb_redo_log_encrypt
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Controls encryption of redo log data for tables encrypted using the InnoDB tablespace encryption feature. Encryption of redo log data is disabled by default. For more information, see Redo Log Data Encryption.

  • innodb_replication_delay

    Command-Line Format--innodb-replication-delay=#
    System VariableNameinnodb_replication_delay
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0
    Maximum4294967295

    The replication thread delay in milliseconds on a slave server if innodb_thread_concurrency is reached.

  • innodb_rollback_on_timeout

    Command-Line Format--innodb-rollback-on-timeout
    System VariableNameinnodb_rollback_on_timeout
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    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.

    Note

    If the start-transaction statement was START TRANSACTION or BEGIN statement, rollback does not cancel that statement. Further SQL statements become part of the transaction until the occurrence of COMMIT, ROLLBACK, or some SQL statement that causes an implicit commit.

    For more information, see Section 15.20.4, “InnoDB Error Handling”.

  • innodb_rollback_segments

    Command-Line Format--innodb-rollback-segments=#
    System VariableNameinnodb_rollback_segments
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default128
    Minimum1
    Maximum128

    innodb_rollback_segments defines the number of rollback segments allocated to the temporary tablespace and each undo tablespace. Each rollback segment can support a maximum of 1023 data-modifying transactions.

    For more information about rollback segments, see Section 15.3, “InnoDB Multi-Versioning”. For information about undo tablespaces, see Section 15.7.7, “Configuring Undo Tablespaces”.

  • innodb_scan_directories

    Introduced8.0.2
    Command-Line Format--innodb-scan-directories=#
    System VariableNameinnodb_scan_directories
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypestring
    DefaultNULL

    If, during recovery, InnoDB encounters redo logs written since the last checkpoint, the redo logs must be applied to affected tablespaces. The process that identifies affected tablespaces is referred to as tablespace discovery. Tablespace discovery depends on tablespace map files that map tablespace IDs in the redo logs to tablespace files. If tablespace map files are lost or corrupted, the innodb_scan_directories startup option can be used to specify tablespace file directories. This option causes InnoDB to read the first page of each tablespace file in the specified directories and recreate tablespace map files so that the recovery process can apply redo logs to affected tablespaces.

    innodb_scan_directories may be specified as an option in a startup command or in a MySQL configuration file. Quotes are used around the argument value because otherwise a semicolon (;) is interpreted as a special character by some command interpreters. (Unix shells treat it as a command terminator, for example.)

    Startup command:

    mysqld --innodb-scan-directories="directory_path_1;directory_path_2"

    MySQL configuration file:

    [mysqld]
    innodb_scan_directories="directory_path_1;directory_path_2"

    For more information, see Lost or Corrupted Tablespace Map Files.

  • innodb_saved_page_number_debug

    Command-Line Format--innodb-saved-page-number-debug=#
    System VariableNameinnodb_saved_page_number_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Maximum2**23-1

    Saves a page number. Setting the innodb_fil_make_page_dirty_debug option dirties the page defined by innodb_saved_page_number_debug. The innodb_saved_page_number_debug option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_sort_buffer_size

    Command-Line Format--innodb-sort-buffer-size=#
    System VariableNameinnodb_sort_buffer_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default1048576
    Minimum65536
    Maximum67108864

    Specifies the size of sort buffers used to sort data during creation of an InnoDB index. The specified size defines the amount of data that is read into memory for internal sorting and then written out to disk. This process is referred to as a run. During the merge phase, pairs of buffers of the specified size are read in and merged. The larger the setting, the fewer runs and merges there are.

    This sort area is only used for merge sorts during index creation, not during later index maintenance operations. Buffers are deallocated when index creation completes.

    The value of this option also controls the amount by which the temporary log file is extended to record concurrent DML during online DDL operations.

    Before this setting was made configurable, the size was hardcoded to 1048576 bytes (1MB), which remains the default.

    During an ALTER TABLE or CREATE TABLE statement that creates an index, 3 buffers are allocated, each with a size defined by this option. Additionally, auxiliary pointers are allocated to rows in the sort buffer so that the sort can run on pointers (as opposed to moving rows during the sort operation).

    For a typical sort operation, a formula such as this one can be used to estimate memory consumption:

    (6 /*FTS_NUM_AUX_INDEX*/ * (3*@@global.innodb_sort_buffer_size)
    + 2 * number_of_partitions * number_of_secondary_indexes_created
    * (@@global.innodb_sort_buffer_size/dict_index_get_min_size(index)*/)
    * 8 /*64-bit sizeof *buf->tuples*/")

    @@global.innodb_sort_buffer_size/dict_index_get_min_size(index) indicates the maximum tuples held. 2 * (@@global.innodb_sort_buffer_size/*dict_index_get_min_size(index)*/) * 8 /*64-bit size of *buf->tuples*/ indicates auxiliary pointers allocated.

    Note

    For 32-bit, multiply by 4 instead of 8.

    For parallel sorts on a full-text index, multiply by the innodb_ft_sort_pll_degree setting:

    (6 /*FTS_NUM_AUX_INDEX*/ * @@global.innodb_ft_sort_pll_degree)
  • innodb_spin_wait_delay

    Command-Line Format--innodb-spin-wait-delay=#
    System VariableNameinnodb_spin_wait_delay
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default6
    Minimum0
    Maximum2**32-1
    Permitted Values (64-bit platforms)Typeinteger
    Default6
    Minimum0
    Maximum2**64-1

    The maximum delay between polls for a spin lock. The low-level implementation of this mechanism varies depending on the combination of hardware and operating system, so the delay does not correspond to a fixed time interval. For more information, see Section 15.6.9, “Configuring Spin Lock Polling”.

  • innodb_stats_auto_recalc

    Command-Line Format--innodb-stats-auto-recalc=#
    System VariableNameinnodb_stats_auto_recalc
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Causes InnoDB to automatically recalculate persistent statistics after the data in a table is changed substantially. The threshold value is 10% of the rows in the table. This setting applies to tables created when the innodb_stats_persistent option is enabled. Automatic statistics recalculation may also be configured by specifying STATS_PERSISTENT=1 in a CREATE TABLE or ALTER TABLE statement. The amount of data sampled to produce the statistics is controlled by the innodb_stats_persistent_sample_pages configuration option.

    For more information, see Section 15.6.11.1, “Configuring Persistent Optimizer Statistics Parameters”.

  • innodb_stats_include_delete_marked

    Introduced8.0.1
    Command-Line Format--innodb-stats-include-delete-marked=#
    System VariableNameinnodb_stats_include_delete_marked
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    By default, InnoDB reads uncommitted data when calculating statistics. In the case of an uncommitted transaction that deletes rows from a table, InnoDB excludes records that are delete-marked when calculating row estimates and index statistics, which can lead to non-optimal execution plans for other transactions that are operating on the table concurrently using a transaction isolation level other than READ UNCOMMITTED. To avoid this scenario, innodb_stats_include_delete_marked can be enabled to ensure that InnoDB includes delete-marked records when calculating persistent optimizer statistics.

    When innodb_stats_include_delete_marked is enabled, ANALYZE TABLE considers delete-marked records when recalculating statistics.

    innodb_stats_include_delete_marked is a global setting that affects all InnoDB tables. It is only applicable to persistent optimizer statistics.

    For related information, see Section 15.6.11.1, “Configuring Persistent Optimizer Statistics Parameters”.

  • innodb_stats_method

    Command-Line Format--innodb-stats-method=name
    System VariableNameinnodb_stats_method
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeenumeration
    Defaultnulls_equal
    Valid Valuesnulls_equal
    nulls_unequal
    nulls_ignored

    How the server treats NULL values when collecting statistics about the distribution of index values for InnoDB tables. Permitted values are nulls_equal, nulls_unequal, and nulls_ignored. For nulls_equal, all NULL index values are considered equal and form a single value group with a size equal to the number of NULL values. For nulls_unequal, NULL values are considered unequal, and each NULL forms a distinct value group of size 1. For nulls_ignored, NULL values are ignored.

    The method used to generate table statistics influences how the optimizer chooses indexes for query execution, as described in Section 8.3.8, “InnoDB and MyISAM Index Statistics Collection”.

  • innodb_stats_on_metadata

    Command-Line Format--innodb-stats-on-metadata
    System VariableNameinnodb_stats_on_metadata
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    This option only applies when optimizer statistics are configured to be non-persistent. Optimizer statistics are not persisted to disk when innodb_stats_persistent is disabled or when individual tables are created or altered with STATS_PERSISTENT=0. For more information, see Section 15.6.11.2, “Configuring Non-Persistent Optimizer Statistics Parameters”.

    When innodb_stats_on_metadata is enabled, InnoDB updates non-persistent statistics when metadata statements such as SHOW TABLE STATUS or when accessing the INFORMATION_SCHEMA.TABLES or INFORMATION_SCHEMA.STATISTICS tables. (These updates are similar to what happens for ANALYZE TABLE.) When disabled, InnoDB does not update statistics during these operations. Leaving the setting disabled 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.

    To change the setting, issue the statement SET GLOBAL innodb_stats_on_metadata=mode, where mode is either ON or OFF (or 1 or 0). Changing the setting requires the SYSTEM_VARIABLES_ADMIN or SUPER privilege and immediately affects the operation of all connections.

  • innodb_stats_persistent

    Command-Line Format--innodb-stats-persistent=setting
    System VariableNameinnodb_stats_persistent
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON
    Valid ValuesOFF
    ON
    0
    1

    Specifies whether InnoDB index statistics are persisted to disk. Otherwise, statistics may be recalculated frequently which can lead to variations in query execution plans. This setting is stored with each table when the table is created. You can set innodb_stats_persistent at the global level before creating a table, or use the STATS_PERSISTENT clause of the CREATE TABLE and ALTER TABLE statements to override the system-wide setting and configure persistent statistics for individual tables.

    For more information, see Section 15.6.11.1, “Configuring Persistent Optimizer Statistics Parameters”.

  • innodb_stats_persistent_sample_pages

    Command-Line Format--innodb-stats-persistent-sample-pages=#
    System VariableNameinnodb_stats_persistent_sample_pages
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default20

    The number of index pages to sample when estimating cardinality and other statistics for an indexed column, such as those calculated by ANALYZE TABLE. Increasing the value improves the accuracy of index statistics, which can improve the query execution plan, at the expense of increased I/O during the execution of ANALYZE TABLE for an InnoDB table. For more information, see Section 15.6.11.1, “Configuring Persistent Optimizer Statistics Parameters”.

    Note

    Setting a high value for innodb_stats_persistent_sample_pages could result in lengthy ANALYZE TABLE execution time. To estimate the number of database pages accessed by ANALYZE TABLE, see Section 15.6.11.3, “Estimating ANALYZE TABLE Complexity for InnoDB Tables”.

    innodb_stats_persistent_sample_pages only applies when innodb_stats_persistent is enabled for a table; when innodb_stats_persistent is disabled, innodb_stats_transient_sample_pages applies instead.

  • innodb_stats_transient_sample_pages

    Command-Line Format--innodb-stats-transient-sample-pages=#
    System VariableNameinnodb_stats_transient_sample_pages
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default8

    The number of index pages to sample when estimating cardinality and other statistics for an indexed column, such as those calculated by ANALYZE TABLE. The default value is 8. Increasing the value improves the accuracy of index statistics, which can improve the query execution plan, at the expense of increased I/O when opening an InnoDB table or recalculating statistics. For more information, see Section 15.6.11.2, “Configuring Non-Persistent Optimizer Statistics Parameters”.

    Note

    Setting a high value for innodb_stats_transient_sample_pages could result in lengthy ANALYZE TABLE execution time. To estimate the number of database pages accessed by ANALYZE TABLE, see Section 15.6.11.3, “Estimating ANALYZE TABLE Complexity for InnoDB Tables”.

    innodb_stats_transient_sample_pages only applies when innodb_stats_persistent is disabled for a table; when innodb_stats_persistent is enabled, innodb_stats_persistent_sample_pages applies instead. Takes the place of innodb_stats_sample_pages. For more information, see Section 15.6.11.2, “Configuring Non-Persistent Optimizer Statistics Parameters”.

  • innodb_status_output

    Command-Line Format--innodb-status-output
    System VariableNameinnodb_status_output
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enables or disables periodic output for the standard InnoDB Monitor. Also used in combination with innodb_status_output_locks to enable or disable periodic output for the InnoDB Lock Monitor. For more information, see Section 15.16.2, “Enabling InnoDB Monitors”.

  • innodb_status_output_locks

    Command-Line Format--innodb-status-output-locks
    System VariableNameinnodb_status_output_locks
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enables or disables the InnoDB Lock Monitor. When enabled, the InnoDB Lock Monitor prints additional information about locks in SHOW ENGINE INNODB STATUS output and in periodic output printed to the MySQL error log. Periodic output for the InnoDB Lock Monitor is printed as part of the standard InnoDB Monitor output. The standard InnoDB Monitor must therefore be enabled for the InnoDB Lock Monitor to print data to the MySQL error log periodically. For more information, see Section 15.16.2, “Enabling InnoDB Monitors”.

  • innodb_strict_mode

    Command-Line Format--innodb-strict-mode=#
    System VariableNameinnodb_strict_mode
    ScopeGlobal, Session
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    When innodb_strict_mode is enabled, InnoDB returns errors rather than warnings for certain conditions.

    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_mode is enabled, InnoDB raises error conditions in certain cases, rather than issuing a warning and processing the specified statement (perhaps with unintended behavior). This is analogous to sql_mode in 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_mode setting affects the handling of syntax errors for CREATE TABLE, ALTER TABLE, CREATE INDEX, and OPTIMIZE TABLE statements. innodb_strict_mode also enables a record size check, so that an INSERT or UPDATE never fails due to the record being too large for the selected page size.

    Oracle recommends enabling innodb_strict_mode when using ROW_FORMAT and KEY_BLOCK_SIZE clauses in CREATE TABLE, ALTER TABLE, and CREATE INDEX statements. When innodb_strict_mode is disabled, InnoDB ignores conflicting clauses and creates the table or index with only a warning in the message log. The resulting table might have different characteristics than intended, such as lack of compression support when attempting to create a compressed table. When innodb_strict_mode is enabled, such problems generate an immediate error and the table or index is not created.

    You can enable or disable innodb_strict_mode on the command line when starting mysqld, or in a MySQL configuration file. You can also enable or disable innodb_strict_mode at runtime with the statement SET [GLOBAL|SESSION] innodb_strict_mode=mode, where mode is either ON or OFF. Changing the GLOBAL setting requires the SYSTEM_VARIABLES_ADMIN or SUPER privilege and affects the operation of all clients that subsequently connect. Any client can change the SESSION setting for innodb_strict_mode, and the setting affects only that client.

    innodb_strict_mode is not applicable to general tablespaces. Tablespace management rules for general tablespaces are strictly enforced independently of innodb_strict_mode. For more information, see Section 13.1.18, “CREATE TABLESPACE Syntax”.

  • innodb_sync_array_size

    Command-Line Format--innodb-sync-array-size=#
    System VariableNameinnodb_sync_array_size
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default1
    Minimum1
    Maximum1024

    Defines the size of the mutex/lock wait array. Increasing the value splits the internal data structure used to coordinate threads, for higher concurrency in workloads with large numbers of waiting threads. This setting must be configured when the MySQL instance is starting up, and cannot be changed afterward. Increasing the value is recommended for workloads that frequently produce a large number of waiting threads, typically greater than 768.

  • innodb_sync_spin_loops

    Command-Line Format--innodb-sync-spin-loops=#
    System VariableNameinnodb_sync_spin_loops
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default30
    Minimum0
    Maximum4294967295

    The number of times a thread waits for an InnoDB mutex to be freed before the thread is suspended.

  • innodb_sync_debug

    Command-Line Format--innodb-sync-debug=#
    System VariableNameinnodb_sync_debug
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Enables sync debug checking for the InnoDB storage engine. This option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_table_locks

    Command-Line Format--innodb-table-locks
    System VariableNameinnodb_table_locks
    ScopeGlobal, Session
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultTRUE

    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.

    In MySQL 8.0, innodb_table_locks = 0 has no effect for tables locked explicitly with LOCK TABLES ... WRITE. It does have an effect for tables locked for read or write by LOCK TABLES ... WRITE implicitly (for example, through triggers) or by LOCK TABLES ... READ.

    For related information, see Section 15.5, “InnoDB Locking and Transaction Model”.

  • innodb_temp_data_file_path

    Command-Line Format--innodb-temp-data-file-path=file
    System VariableNameinnodb_temp_data_file_path
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypestring
    Defaultibtmp1:12M:autoextend

    Defines the relative path, name, size, and attributes of InnoDB temporary tablespace data files. If you do not specify a value for innodb_temp_data_file_path, the default behavior is to create a single auto-extending data file, slightly larger than 12MB, named ibtmp1.

    The full syntax for a temporary tablespace data file specification includes the file name, file size, and autoextend and max attributes:

    file_name:file_size[:autoextend[:max:max_file_size]]

    The temporary tablespace data file cannot have the same name as another InnoDB data file. Any inability or error creating a temporary tablespace data file is treated as fatal and server startup is refused. The temporary tablespace has a dynamically generated space ID, which can change on each server restart.

    File sizes are specified 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 slightly larger than 12MB.

    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. Use of raw disk partitions for temporary tablespace data files is not supported.

    The autoextend and max attributes can be used only for the data file that is specified last in the innodb_temp_data_file_path setting. For example:

    [mysqld]
    innodb_temp_data_file_path=ibtmp1:50M;ibtmp2:12M:autoextend:max:500MB

    If you specify the autoextend option, InnoDB extends the data file if it runs out of free space. The autoextend increment is 64MB by default. To modify the increment, change the innodb_autoextend_increment system variable.

    The full directory path for temporary tablespace data files is formed by concatenating the paths defined by innodb_data_home_dir and innodb_temp_data_file_path.

    The temporary tablespace is shared by all InnoDB temporary tables.

    Before running InnoDB in read-only mode, set innodb_temp_data_file_path to a location outside of the data directory. The path must be relative to the data directory. For example:

    --innodb_temp_data_file_path=../../../tmp/ibtmp1:12M:autoextend

    Metadata about active InnoDB temporary tables is located in INFORMATION_SCHEMA.INNODB_TEMP_TABLE_INFO.

    For related information, see Section 15.4.11, “Temporary Tablespace”.

  • innodb_tmpdir

    Command-Line Format--innodb-tmpdir=path
    System VariableNameinnodb_tmpdir
    ScopeGlobal, Session
    DynamicYes
    HintableNo
    Permitted ValuesTypedirectory name
    DefaultNULL

    Used to define an alternate directory for temporary sort files created during online ALTER TABLE operations that rebuild the table.

    Online ALTER TABLE operations that rebuild the table also create an intermediate table file in the same directory as the original table. The innodb_tmpdir option is not applicable to intermediate table files.

    A valid value is any directory path other than the MySQL data directory path. If the value is NULL (the default), temporary files are created MySQL temporary directory ($TMPDIR on Unix, %TEMP% on Windows, or the directory specified by the --tmpdir configuration option). If a directory is specified, existence of the directory and permissions are only checked when innodb_tmpdir is configured using a SET statement. If a symlink is provided in a directory string, the symlink is resolved and stored as an absolute path. The path should not exceed 512 bytes. An online ALTER TABLE operation reports an error if innodb_tmpdir is set to an invalid directory. innodb_tmpdir overrides the MySQL tmpdir setting but only for online ALTER TABLE operations.

    The FILE privilege is required to configure innodb_tmpdir.

    The innodb_tmpdir option was introduced to help avoid overflowing a temporary file directory located on a tmpfs file system. Such overflows could occur as a result of large temporary sort files created during online ALTER TABLE operations that rebuild the table.

    In replication environments, only consider replicating the innodb_tmpdir setting if all servers have the same operating system environment. Otherwise, replicating the innodb_tmpdir setting could result in a replication failure when running online ALTER TABLE operations that rebuild the table. If server operating environments differ, it is recommended that you configure innodb_tmpdir on each server individually.

    For more information, see Where InnoDB Stores Temporary Files. For information about online ALTER TABLE operations, see Section 15.12, “InnoDB and Online DDL”.

  • innodb_thread_concurrency

    Command-Line Format--innodb-thread-concurrency=#
    System VariableNameinnodb_thread_concurrency
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Minimum0
    Maximum1000

    InnoDB tries to keep the number of operating system threads concurrently inside InnoDB less than or equal to the limit given by this variable (InnoDB uses 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 InnoDB to create as many threads as it needs. A value of 0 also disables the queries inside InnoDB and queries in queue counters in the ROW OPERATIONS section of SHOW ENGINE INNODB STATUS output.

    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_concurrency is 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 set innodb_thread_concurrency back 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 then 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 set innodb_thread_concurrency=80 to avoid impacting performance.

    • If you do not want InnoDB to use more than a certain number of vCPUs for user threads (20 vCPUs, for example), set innodb_thread_concurrency to this number (or possibly lower, depending on performance results). If your goal is to isolate MySQL from other applications, you may consider binding the mysqld process exclusively to the vCPUs. Be aware, however, that exclusive binding could result in non-optimal hardware usage if the mysqld process is not consistently busy. In this case, you might bind the mysqld process to the vCPUs but also allow other applications to use some or all of the vCPUs.

      Note

      From an operating system perspective, using a resource management solution to manage how CPU time is shared among applications may be preferable to binding the mysqld process. 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_concurrency values that are too high can cause performance regression due to increased contention on system internals and resources.

    • In some cases, the optimal innodb_thread_concurrency setting 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_concurrency setting.

    For related information, see Section 15.6.5, “Configuring Thread Concurrency for InnoDB”.

  • innodb_trx_purge_view_update_only_debug

    Command-Line Format--innodb-trx-purge-view-update-only-debug=#
    System VariableNameinnodb_trx_purge_view_update_only_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Pauses 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_DEBUG CMake option.

  • innodb_trx_rseg_n_slots_debug

    Command-Line Format--innodb-trx-rseg-n-slots-debug=#
    System VariableNameinnodb_trx_rseg_n_slots_debug
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default0
    Maximum1024

    Sets a debug flag that limits TRX_RSEG_N_SLOTS to a given value for the trx_rsegf_undo_find_free function that looks for free slots for undo log segments. This option is only available if debugging support is compiled in using the WITH_DEBUG CMake option.

  • innodb_thread_sleep_delay

    Command-Line Format--innodb-thread-sleep-delay=#
    System VariableNameinnodb_thread_sleep_delay
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default10000
    Minimum0
    Maximum1000000

    How long InnoDB threads sleep before joining the InnoDB queue, in microseconds. The default value is 10000. A value of 0 disables sleep. You can set the configuration option innodb_adaptive_max_sleep_delay to the highest value you would allow for innodb_thread_sleep_delay, and InnoDB automatically adjusts innodb_thread_sleep_delay up or down depending on current thread-scheduling activity. This dynamic adjustment helps the thread scheduling mechanism to work smoothly during times when the system is lightly loaded or when it is operating near full capacity.

    For more information, see Section 15.6.5, “Configuring Thread Concurrency for InnoDB”.

  • innodb_undo_directory

    Command-Line Format--innodb-undo-directory=dir_name
    System VariableNameinnodb_undo_directory
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypedirectory name

    The path where InnoDB creates undo tablespaces. Typically used to place undo logs on a different storage device. Used in conjunction with innodb_rollback_segments and innodb_undo_tablespaces.

    There is no default value (it is NULL). If a path is not specified, undo tablespaces are created in the MySQL data directory, as defined by datadir.

    For more information, see Section 15.7.7, “Configuring Undo Tablespaces”.

  • innodb_undo_log_encrypt

    Introduced8.0.1
    Command-Line Format--innodb-undo-log-encrypt=#
    System VariableNameinnodb_undo_log_encrypt
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeboolean
    DefaultOFF

    Controls encryption of undo log data for tables encrypted using the InnoDB tablespace encryption feature. Only applies to undo logs that reside in separate undo tablespaces. See Section 15.7.7, “Configuring Undo Tablespaces”. Encryption is not supported for undo log data that resides in the system tablespace. For more information, see Undo Log Data Encryption.

  • innodb_undo_log_truncate

    Command-Line Format--innodb-undo-log-truncate=#
    System VariableNameinnodb_undo_log_truncate
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (<= 8.0.1)Typeboolean
    DefaultOFF
    Permitted Values (>= 8.0.2)Typeboolean
    DefaultON

    When enabled, undo tablespaces that exceed the threshold value defined by innodb_max_undo_log_size are marked for truncation. Only undo tablespaces can be truncated. Truncating undo logs that reside in the system tablespace is not supported. For truncation to occur, there must be at least two undo tablespaces.

    The innodb_purge_rseg_truncate_frequency configuration option can be used to expedite truncation of undo tablepaces.

    For more information, see Section 15.7.8, “Truncating Undo Tablespaces”.

  • innodb_undo_logs

    Deprecated5.7.19
    Removed8.0.2
    Command-Line Format--innodb-undo-logs=#
    System VariableNameinnodb_undo_logs
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted ValuesTypeinteger
    Default128
    Minimum1
    Maximum128
    Note

    innodb_undo_logs was removed in MySQL 8.0.2.

    The innodb_undo_logs option is an alias for innodb_rollback_segments. For more information, see the description of innodb_rollback_segments.

  • innodb_undo_tablespaces

    Deprecated8.0.4
    Command-Line Format--innodb-undo-tablespaces=#
    System Variable (<= 8.0.1)Nameinnodb_undo_tablespaces
    ScopeGlobal
    DynamicNo
    HintableNo
    System Variable (>= 8.0.2)Nameinnodb_undo_tablespaces
    ScopeGlobal
    DynamicYes
    HintableNo
    Permitted Values (<= 8.0.1)Typeinteger
    Default0
    Minimum0
    Maximum95
    Permitted Values (8.0.2)Typeinteger
    Default2
    Minimum0
    Maximum127
    Permitted Values (>= 8.0.3)Typeinteger
    Default2
    Minimum2
    Maximum127

    The number of undo tablespaces used by InnoDB. The default and minimum value is 2.

    Note

    innodb_undo_tablespaces is deprecated and will be removed in a future release.

    Undo logs can become large during long-running transactions. Using multiple undo tablespaces reduces the size of any one undo tablespace.

    In previous releases, innodb_undo_tablespaces could be set to 0 to use the system tablespace for rollback segments. A value greater than 0 meant that rollback segments in the system tablespace were no longer assigned to transactions. As of MySQL 8.0, a setting of 0 is no longer permitted and rollback segments are only created in undo tablespaces.

    Undo tablespace files are created in the location defined by innodb_undo_directory. File names are in the form of undo_NNN, where NNN is the undo space number.

    The initial size of an undo tablespace file depends on the innodb_page_size value. For the default 16k InnoDB page size, the initial undo tablespace file size is 10MiB. For 4k, 8k, 32k, and 64k page sizes, the initial undo tablespace files sizes are 7MiB, 8MiB, 20MiB, and 40MiB, respectively.

    innodb_undo_tablespaces may be configured at startup or while the server is running. Increasing the innodb_undo_tablespaces setting creates the specified number of undo tablespaces and adds them to the list of active undo tablespaces. Decreasing the innodb_undo_tablespaces setting removes undo tablespaces from the list of active undo tablespaces. However, these undo tablespaces remain active until they are no longer used by existing transactions. Undo tablespaces are made inactive rather than deleted so that the number of active undo tablespaces can be increased again easily.

    For more information, see Section 15.7.7, “Configuring Undo Tablespaces”.

  • innodb_use_native_aio

    Command-Line Format--innodb-use-native-aio=#
    System VariableNameinnodb_use_native_aio
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeboolean
    DefaultON

    Specifies whether to use the Linux asynchronous I/O subsystem. This variable applies to Linux systems only, and cannot be changed while the server is running. Normally, you do not need to configure this option, because it is enabled by default.

    The asynchronous I/O capability that InnoDB has 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 SHOW ENGINE INNODB STATUS\G output.

    Running with a large number of InnoDB I/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 InnoDB from starting, you can start the server with innodb_use_native_aio=0. This option may also be disabled automatically during startup if InnoDB detects a potential problem such as a combination of tmpdir location, tmpfs file system, and Linux kernel that does not support AIO on tmpfs.

    For more information, see Section 15.6.7, “Using Asynchronous I/O on Linux”.

  • innodb_version

    The InnoDB version number. In MySQL 8.0, separate version numbering for InnoDB does not apply and this value is the same the version number of the server.

  • innodb_write_io_threads

    Command-Line Format--innodb-write-io-threads=#
    System VariableNameinnodb_write_io_threads
    ScopeGlobal
    DynamicNo
    HintableNo
    Permitted ValuesTypeinteger
    Default4
    Minimum1
    Maximum64

    The number of I/O threads for write operations in InnoDB. The default value is 4. Its counterpart for read threads is innodb_read_io_threads. For more information, see Section 15.6.6, “Configuring the Number of Background InnoDB I/O Threads”. For general I/O tuning advice, see Section 8.5.8, “Optimizing InnoDB Disk I/O”.

    Note

    On Linux systems, running multiple MySQL servers (typically more than 12) with default settings for innodb_read_io_threads, innodb_write_io_threads, and the Linux aio-max-nr setting can exceed system limits. Ideally, increase the aio-max-nr setting; as a workaround, you might reduce the settings for one or both of the MySQL configuration options.

    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.8, “Optimizing InnoDB Disk I/O”.


User Comments
  Posted by Morgan Tocker on December 28, 2006
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.
  Posted by Brian Aker on August 16, 2007
Commentary on Innodb parameters for an 8way machine:
http://krow.livejournal.com/542306.html
  Posted by Willem de Groot on September 20, 2007
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).

  Posted by Simon Mudd on October 13, 2009
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.

  Posted by Morgan Tocker on November 15, 2013
I wrote a guide for what to tune in MySQL 5.6 after installation here:
http://www.tocker.ca/2013/09/17/what-to-tune-in-mysql-56-after-installation.html
Sign Up Login You must be logged in to post a comment.