MySQL 5.0 Reference Manual  /  ...  /  Server System Variables

5.1.4 Server System Variables

The MySQL server maintains many system variables that indicate how it is configured. Each system variable has a default value. System variables can be set at server startup using options on the command line or in an option file. Most of them can be changed dynamically while the server is running by means of the SET statement, which enables you to modify operation of the server without having to stop and restart it. You can refer to system variable values in expressions.

There are several ways to see the names and values of system variables:

  • To see the values that a server will use based on its compiled-in defaults and any option files that it reads, use this command:

    mysqld --verbose --help
    
  • To see the values that a server will use based on its compiled-in defaults, ignoring the settings in any option files, use this command:

    mysqld --no-defaults --verbose --help
    
  • To see the current values used by a running server, use the SHOW VARIABLES statement.

This section provides a description of each system variable. Variables with no version indicated are present in all MySQL 5.0 releases.

The following table lists all available system variables.

Table 5.2 System Variable Summary

NameCmd-LineOption FileSystem VarVar ScopeDynamic
auto_increment_increment  YesBothYes
auto_increment_offset  YesBothYes
autocommit  YesSessionYes
automatic_sp_privileges  YesGlobalYes
back_log  YesGlobalNo
basedirYesYesYesGlobalNo
bdb_cache_size  YesGlobalNo
bdb-homeYesYes  No
- Variable: bdb_home  YesGlobalNo
bdb-lock-detectYesYesYesGlobalNo
bdb_log_buffer_size  YesGlobalNo
bdb-logdirYesYes  No
- Variable: bdb_logdir  YesGlobalNo
bdb_max_lock  YesGlobalNo
bdb-shared-dataYesYes  No
- Variable: bdb_shared_data  YesGlobalNo
bdb-tmpdirYesYes  No
- Variable: bdb_tmpdir  YesGlobalNo
big-tablesYesYes  Yes
- Variable: big_tables  YesSessionYes
binlog_cache_sizeYesYesYesGlobalYes
bulk_insert_buffer_sizeYesYesYesBothYes
character_set_client  YesBothYes
character_set_connection  YesBothYes
character_set_database[a]  YesBothYes
character-set-filesystemYesYes  Yes
- Variable: character_set_filesystem  YesBothYes
character_set_results  YesBothYes
character-set-serverYesYes  Yes
- Variable: character_set_server  YesBothYes
character_set_system  YesGlobalNo
character-sets-dirYesYes  No
- Variable: character_sets_dir  YesGlobalNo
collation_connection  YesBothYes
collation_database[b]  YesBothYes
collation-serverYesYes  Yes
- Variable: collation_server  YesBothYes
completion_typeYesYesYesBothYes
concurrent_insertYesYesYesGlobalYes
connect_timeoutYesYesYesGlobalYes
datadirYesYesYesGlobalNo
date_format  YesBothNo
datetime_format  YesBothNo
debugYesYesYesBothYes
default-storage-engineYesYesYesBothYes
default_week_formatYesYesYesBothYes
delay-key-writeYesYes  Yes
- Variable: delay_key_write  YesGlobalYes
delayed_insert_limitYesYesYesGlobalYes
delayed_insert_timeoutYesYesYesGlobalYes
delayed_queue_sizeYesYesYesGlobalYes
div_precision_incrementYesYesYesBothYes
engine-condition-pushdownYesYes  Yes
- Variable: engine_condition_pushdown  YesBothYes
error_count  YesSessionNo
expire_logs_daysYesYesYesGlobalYes
flushYesYesYesGlobalYes
flush_timeYesYesYesGlobalYes
foreign_key_checks  YesSessionYes
ft_boolean_syntaxYesYesYesGlobalYes
ft_max_word_lenYesYesYesGlobalNo
ft_min_word_lenYesYesYesGlobalNo
ft_query_expansion_limitYesYesYesGlobalNo
ft_stopword_fileYesYesYesGlobalNo
group_concat_max_lenYesYesYesBothYes
have_archive  YesGlobalNo
have_bdb  YesGlobalNo
have_blackhole_engine  YesGlobalNo
have_community_features  YesGlobalNo
have_compress  YesGlobalNo
have_crypt  YesGlobalNo
have_csv  YesGlobalNo
have_example_engine  YesGlobalNo
have_federated_engine  YesGlobalNo
have_geometry  YesGlobalNo
have_innodb  YesGlobalNo
have_isam  YesGlobalNo
have_merge_engine  YesGlobalNo
have_ndbcluster  YesGlobalNo
have_openssl  YesGlobalNo
have_profiling  YesGlobalNo
have_query_cache  YesGlobalNo
have_raid  YesGlobalNo
have_rtree_keys  YesGlobalNo
have_ssl  YesGlobalNo
have_symlink  YesGlobalNo
hostname  YesGlobalNo
identity  YesSessionYes
init_connectYesYesYesGlobalYes
init-fileYesYes  No
- Variable: init_file  YesGlobalNo
init_slaveYesYesYesGlobalYes
innodb_adaptive_hash_indexYesYesYesGlobalNo
innodb_additional_mem_pool_sizeYesYesYesGlobalNo
innodb_autoextend_incrementYesYesYesGlobalYes
innodb_buffer_pool_awe_mem_mbYesYesYesGlobalNo
innodb_buffer_pool_sizeYesYesYesGlobalNo
innodb_checksumsYesYesYesGlobalNo
innodb_commit_concurrencyYesYesYesGlobalYes
innodb_concurrency_ticketsYesYesYesGlobalYes
innodb_data_file_pathYesYesYesGlobalNo
innodb_data_home_dirYesYesYesGlobalNo
innodb_doublewriteYesYesYesGlobalNo
innodb_fast_shutdownYesYesYesGlobalYes
innodb_file_io_threadsYesYesYesGlobalNo
innodb_file_per_tableYesYesYesGlobalNo
innodb_flush_log_at_trx_commitYesYesYesGlobalYes
innodb_flush_methodYesYesYesGlobalNo
innodb_force_recoveryYesYesYesGlobalNo
innodb_lock_wait_timeoutYesYesYesGlobalNo
innodb_locks_unsafe_for_binlogYesYesYesGlobalNo
innodb_log_arch_dirYesYesYesGlobalNo
innodb_log_archiveYesYesYesGlobalNo
innodb_log_buffer_sizeYesYesYesGlobalNo
innodb_log_file_sizeYesYesYesGlobalNo
innodb_log_files_in_groupYesYesYesGlobalNo
innodb_log_group_home_dirYesYesYesGlobalNo
innodb_max_dirty_pages_pctYesYesYesGlobalYes
innodb_max_purge_lagYesYesYesGlobalYes
innodb_mirrored_log_groupsYesYesYesGlobalNo
innodb_open_filesYesYesYesGlobalNo
innodb_rollback_on_timeoutYesYesYesGlobalNo
innodb_support_xaYesYesYesBothYes
innodb_sync_spin_loopsYesYesYesGlobalYes
innodb_table_locksYesYesYesBothYes
innodb_thread_concurrencyYesYesYesGlobalYes
innodb_thread_sleep_delayYesYesYesGlobalYes
innodb_use_legacy_cardinality_algorithmYesYesYesGlobalYes
insert_id  YesSessionYes
interactive_timeoutYesYesYesBothYes
join_buffer_sizeYesYesYesBothYes
keep_files_on_createYesYesYesBothYes
key_buffer_sizeYesYesYesGlobalYes
key_cache_age_thresholdYesYesYesGlobalYes
key_cache_block_sizeYesYesYesGlobalYes
key_cache_division_limitYesYesYesGlobalYes
languageYesYesYesGlobalNo
large_files_support  YesGlobalNo
large_page_size  YesGlobalNo
large-pagesYesYes  No
- Variable: large_pages  YesGlobalNo
last_insert_id  YesSessionYes
lc_time_names  YesBothYes
license  YesGlobalNo
local_infile  YesGlobalYes
locked_in_memory  YesGlobalNo
logYesYesYesGlobalNo
log-binYesYesYesGlobalNo
log_bin  YesGlobalNo
log-bin-trust-function-creatorsYesYes  Yes
- Variable: log_bin_trust_function_creators  YesGlobalYes
log-bin-trust-routine-creatorsYesYes  Yes
- Variable: log_bin_trust_routine_creators  YesGlobalYes
log-errorYesYes  No
- Variable: log_error  YesGlobalNo
log-queries-not-using-indexesYesYes  Yes
- Variable: log_queries_not_using_indexes  YesGlobalYes
log-slave-updatesYesYes  No
- Variable: log_slave_updates  YesGlobalNo
log_slave_updatesYesYesYesGlobalNo
log-slow-queriesYesYes  No
- Variable: log_slow_queries  YesGlobalNo
log-warningsYesYes  Yes
- Variable: log_warnings  YesBothYes
long_query_timeYesYesYesBothYes
low-priority-updatesYesYes  Yes
- Variable: low_priority_updates  YesBothYes
lower_case_file_system  YesGlobalNo
lower_case_table_namesYesYesYesGlobalNo
max_allowed_packetYesYesYesBothYes
max_binlog_cache_sizeYesYesYesGlobalYes
max_binlog_sizeYesYesYesGlobalYes
max_connect_errorsYesYesYesGlobalYes
max_connectionsYesYesYesGlobalYes
max_delayed_threadsYesYesYesBothYes
max_error_countYesYesYesBothYes
max_heap_table_sizeYesYesYesBothYes
max_insert_delayed_threads  YesBothYes
max_join_sizeYesYesYesBothYes
max_length_for_sort_dataYesYesYesBothYes
max_prepared_stmt_countYesYesYesGlobalYes
max_relay_log_sizeYesYesYesGlobalYes
max_seeks_for_keyYesYesYesBothYes
max_sort_lengthYesYesYesBothYes
max_sp_recursion_depthYesYesYesBothYes
max_tmp_tables  YesBothYes
max_user_connectionsYesYesYesVariesYes
max_write_lock_countYesYesYesGlobalYes
multi_range_countYesYesYesBothYes
myisam_data_pointer_sizeYesYesYesGlobalYes
myisam_max_extra_sort_file_sizeYesYesYesGlobalNo
myisam_max_sort_file_sizeYesYesYesGlobalYes
myisam_mmap_sizeYesYesYesGlobalNo
myisam_recover_options  YesGlobalNo
myisam_repair_threadsYesYesYesBothYes
myisam_sort_buffer_sizeYesYesYesBothYes
myisam_stats_methodYesYesYesBothYes
named_pipe  YesGlobalNo
ndb_autoincrement_prefetch_szYesYesYesBothYes
ndb_cache_check_timeYesYesYesGlobalYes
ndb_force_sendYesYesYesBothYes
ndb_index_stat_cache_entriesYesYesYesBothYes
ndb_index_stat_enableYesYesYesBothYes
ndb_index_stat_update_freqYesYesYesBothYes
ndb_optimized_node_selectionYesYesYesGlobalNo
ndb_use_exact_count  YesBothYes
ndb_use_transactionsYesYesYesBothYes
net_buffer_lengthYesYesYesBothYes
net_read_timeoutYesYesYesBothYes
net_retry_countYesYesYesBothYes
net_write_timeoutYesYesYesBothYes
newYesYesYesBothYes
old_passwords  YesBothYes
open-files-limitYesYes  No
- Variable: open_files_limit  YesGlobalNo
optimizer_prune_levelYesYesYesBothYes
optimizer_search_depthYesYesYesBothYes
pid-fileYesYes  No
- Variable: pid_file  YesGlobalNo
plugin_dirYesYesYesGlobalNo
portYesYesYesGlobalNo
preload_buffer_sizeYesYesYesBothYes
prepared_stmt_count  YesGlobalNo
profiling  YesSessionYes
profiling_history_sizeYesYesYesBothYes
protocol_version  YesGlobalNo
pseudo_thread_id  YesSessionYes
query_alloc_block_sizeYesYesYesBothYes
query_cache_limitYesYesYesGlobalYes
query_cache_min_res_unitYesYesYesGlobalYes
query_cache_sizeYesYesYesGlobalYes
query_cache_typeYesYesYesBothYes
query_cache_wlock_invalidateYesYesYesBothYes
query_prealloc_sizeYesYesYesBothYes
rand_seed1  YesSessionYes
rand_seed2  YesSessionYes
range_alloc_block_sizeYesYesYesBothYes
read_buffer_sizeYesYesYesBothYes
read_onlyYesYesYesGlobalYes
read_rnd_buffer_sizeYesYesYesBothYes
relay-logYesYes  No
- Variable: relay_log  YesGlobalNo
relay-log-indexYesYes  No
- Variable: relay_log_index  YesGlobalNo
relay_log_indexYesYesYesGlobalNo
relay_log_info_fileYesYesYesGlobalNo
relay_log_purgeYesYesYesGlobalYes
relay_log_space_limitYesYesYesGlobalNo
rpl_recovery_rank  YesGlobalYes
secure-authYesYes  Yes
- Variable: secure_auth  YesGlobalYes
secure-file-privYesYes  No
- Variable: secure_file_priv  YesGlobalNo
server-idYesYes  Yes
- Variable: server_id  YesGlobalYes
shared_memoryYesYesYesGlobalNo
shared_memory_base_nameYesYesYesGlobalNo
skip_external_lockingYesYesYesGlobalNo
skip-networkingYesYes  No
- Variable: skip_networking  YesGlobalNo
skip-show-databaseYesYes  No
- Variable: skip_show_database  YesGlobalNo
skip-sync-bdb-logsYesYesYesGlobalNo
slave_compressed_protocolYesYesYesGlobalYes
slave-load-tmpdirYesYes  No
- Variable: slave_load_tmpdir  YesGlobalNo
slave-net-timeoutYesYes  Yes
- Variable: slave_net_timeout  YesGlobalYes
slave-skip-errorsYesYes  No
- Variable: slave_skip_errors  YesGlobalNo
slave_transaction_retriesYesYesYesGlobalYes
slow_launch_timeYesYesYesGlobalYes
socketYesYesYesGlobalNo
sort_buffer_sizeYesYesYesBothYes
sql_auto_is_null  YesSessionYes
sql_big_selects  YesSessionYes
sql_big_tables  YesSessionYes
sql_buffer_result  YesSessionYes
sql_log_bin  YesSessionYes
sql_log_off  YesSessionYes
sql_log_update  YesSessionYes
sql_low_priority_updates  YesBothYes
sql_max_join_size  YesBothYes
sql-modeYesYes  Yes
- Variable: sql_mode  YesBothYes
sql_notes  YesSessionYes
sql_quote_show_create  YesSessionYes
sql_safe_updates  YesSessionYes
sql_select_limit  YesBothYes
sql_slave_skip_counter  YesGlobalYes
sql_warnings  YesSessionYes
ssl-caYesYes  No
- Variable: ssl_ca  YesGlobalNo
ssl-capathYesYes  No
- Variable: ssl_capath  YesGlobalNo
ssl-certYesYes  No
- Variable: ssl_cert  YesGlobalNo
ssl-cipherYesYes  No
- Variable: ssl_cipher  YesGlobalNo
ssl-keyYesYes  No
- Variable: ssl_key  YesGlobalNo
storage_engine  YesBothYes
sync-bdb-logsYesYesYesGlobalNo
sync_binlogYesYesYesGlobalYes
sync_frmYesYesYesGlobalYes
system_time_zone  YesGlobalNo
table_cacheYesYesYesGlobalYes
table_lock_wait_timeoutYesYesYesGlobalYes
table_type  YesBothYes
thread_cache_sizeYesYesYesGlobalYes
thread_concurrencyYesYesYesGlobalNo
thread_stackYesYesYesGlobalNo
time_format  YesBothNo
time_zone  YesBothYes
timed_mutexesYesYesYesGlobalYes
timestamp  YesSessionYes
tmp_table_sizeYesYesYesBothYes
tmpdirYesYesYesGlobalNo
transaction_alloc_block_sizeYesYesYesBothYes
transaction_prealloc_sizeYesYesYesBothYes
tx_isolation  YesBothYes
unique_checks  YesSessionYes
updatable_views_with_limitYesYesYesBothYes
version  YesGlobalNo
version_comment  YesGlobalNo
version_compile_machine  YesGlobalNo
version_compile_os  YesGlobalNo
wait_timeoutYesYesYesBothYes
warning_count  YesSessionNo

[a] This option is dynamic, but only the server should set this information. You should not set the value of this variable manually.

[b] This option is dynamic, but only the server should set this information. You should not set the value of this variable manually.


For additional system variable information, see these sections:

Note

Some of the following variable descriptions refer to enabling or disabling a variable. These variables can be enabled with the SET statement by setting them to ON or 1, or disabled by setting them to OFF or 0. However, to set such a variable on the command line or in an option file, you must set it to 1 or 0; setting it to ON or OFF will not work. For example, on the command line, --delay_key_write=1 works but --delay_key_write=ON does not.

Some system variables control the size of buffers or caches. For a given buffer, the server might need to allocate internal data structures. These structures typically are allocated from the total memory allocated to the buffer, and the amount of space required might be platform dependent. This means that when you assign a value to a system variable that controls a buffer size, the amount of space actually available might differ from the value assigned. In some cases, the amount might be less than the value assigned. It is also possible that the server will adjust a value upward. For example, if you assign a value of 0 to a variable for which the minimal value is 1024, the server will set the value to 1024.

Values for buffer sizes, lengths, and stack sizes are given in bytes unless otherwise specified.

Some system variables take file name values. Unless otherwise specified, the default file location is the data directory if the value is a relative path name. To specify the location explicitly, use an absolute path name. Suppose that the data directory is /var/mysql/data. If a file-valued variable is given as a relative path name, it will be located under /var/mysql/data. If the value is an absolute path name, its location is as given by the path name.

  • autocommit

    System VariableNameautocommit
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultON

    The autocommit mode. If set to 1, all changes to a table take effect immediately. If set to 0, you must use COMMIT to accept a transaction or ROLLBACK to cancel it. If autocommit is 0 and you change it to 1, MySQL performs an automatic COMMIT of any open transaction. Another way to begin a transaction is to use a START TRANSACTION or BEGIN statement. See Section 13.3.1, “START TRANSACTION, COMMIT, and ROLLBACK Syntax”.

    By default, client connections begin with autocommit set to 1. To cause clients to begin with a default of 0, set the server's init_connect system variable:

    SET GLOBAL init_connect='SET autocommit=0';
    

    The init_connect variable can also be set on the command line or in an option file. To set the variable as just shown using an option file, include these lines:

    [mysqld]
    init_connect='SET autocommit=0'
    

    The content of init_connect is not executed for users that have the SUPER privilege.

  • automatic_sp_privileges

    Introduced5.0.3
    System VariableNameautomatic_sp_privileges
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultTRUE

    When this variable has a value of 1 (the default), the server automatically grants the EXECUTE and ALTER ROUTINE privileges to the creator of a stored routine, if the user cannot already execute and alter or drop the routine. (The ALTER ROUTINE privilege is required to drop the routine.) The server also automatically drops those privileges from the creator when the routine is dropped. If automatic_sp_privileges is 0, the server does not automatically add or drop these privileges.

    The creator of a routine is the account used to execute the CREATE statement for it. This might not be the same as the account named as the DEFINER in the routine definition.

    See also Section 18.2.2, “Stored Routines and MySQL Privileges”.

    This variable was added in MySQL 5.0.3.

  • back_log

    System VariableNameback_log
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default50
    Min Value1
    Max Value65535

    The number of outstanding connection requests MySQL can have. This comes into play when the main MySQL thread gets very many connection requests in a very short time. It then takes some time (although very little) for the main thread to check the connection and start a new thread. The back_log value indicates how many requests can be stacked during this short time before MySQL momentarily stops answering new requests. You need to increase this only if you expect a large number of connections in a short period of time.

    In other words, this value is the size of the listen queue for incoming TCP/IP connections. Your operating system has its own limit on the size of this queue. The manual page for the Unix listen() system call should have more details. Check your OS documentation for the maximum value for this variable. back_log cannot be set higher than your operating system limit.

  • basedir

    Command-Line Format--basedir=dir_name
    System VariableNamebasedir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The MySQL installation base directory. This variable can be set with the --basedir option. Relative path names for other variables usually are resolved relative to the base directory.

  • bdb_cache_size

    System VariableNamebdb_cache_size
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Min Value20480

    The size of the buffer that is allocated for caching indexes and rows for BDB tables. If you do not use BDB tables, you should start mysqld with --skip-bdb to not allocate memory for this cache.

  • bdb_home

    Command-Line Format--bdb-home=dir_name
    System VariableNamebdb_home
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The base directory for BDB tables. This should be assigned the same value as the datadir variable.

  • bdb_log_buffer_size

    System VariableNamebdb_log_buffer_size
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Min Value262144
    Max Value4294967295

    The size of the buffer that is allocated for caching indexes and rows for BDB tables. If you do not use BDB tables, you should set this to 0 or start mysqld with --skip-bdb to not allocate memory for this cache.

  • bdb_logdir

    Command-Line Format--bdb-logdir=file_name
    System VariableNamebdb_logdir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The directory where the BDB storage engine writes its log files. This variable can be set with the --bdb-logdir option.

  • bdb_max_lock

    System VariableNamebdb_max_lock
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default10000

    The maximum number of locks that can be active for a BDB table (10,000 by default). You should increase this value if errors such as the following occur when you perform long transactions or when mysqld has to examine many rows to calculate a query:

    bdb: Lock table is out of available locks
    Got error 12 from ...
    

    For more information, see Section 21.3.3, “The DBUG Package”.

  • bdb_shared_data

    Command-Line Format--bdb-shared-data
    System VariableNamebdb_shared_data
    Variable ScopeGlobal
    Dynamic VariableNo

    This is ON if you are using --bdb-shared-data to start Berkeley DB in multi-process mode. (Do not use DB_PRIVATE when initializing Berkeley DB.)

  • bdb_tmpdir

    Command-Line Format--bdb-tmpdir=dir_name
    System VariableNamebdb_tmpdir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The BDB temporary file directory.

  • big_tables

    If set to 1, all temporary tables are stored on disk rather than in memory. This is a little slower, but the error The table tbl_name is full does not occur for SELECT operations that require a large temporary table. The default value for a new connection is 0 (use in-memory temporary tables). Normally, you should never need to set this variable, because in-memory tables are automatically converted to disk-based tables as required.

    Note

    This variable was formerly named sql_big_tables.

  • binlog_cache_size

    Command-Line Format--binlog_cache_size=#
    System VariableNamebinlog_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default32768
    Min Value4096
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default32768
    Min Value4096
    Max Value18446744073709547520

    The size of the cache to hold the SQL statements for the binary log during a transaction. A binary log cache is allocated for each client if the server supports any transactional storage engines and if the server has the binary log enabled (--log-bin option). If you often use large, multiple-statement transactions, you can increase this cache size to get better performance. The Binlog_cache_use and Binlog_cache_disk_use status variables can be useful for tuning the size of this variable. See Section 5.4.3, “The Binary Log”.

  • bulk_insert_buffer_size

    Command-Line Format--bulk_insert_buffer_size=#
    System VariableNamebulk_insert_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default8388608
    Min Value0
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default8388608
    Min Value0
    Max Value18446744073709547520

    MyISAM uses a special tree-like cache to make bulk inserts faster for INSERT ... SELECT, INSERT ... VALUES (...), (...), ..., and LOAD DATA INFILE when adding data to nonempty tables. This variable limits the size of the cache tree in bytes per thread. Setting it to 0 disables this optimization. The default value is 8MB.

  • character_set_client

    System VariableNamecharacter_set_client
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring

    The character set for statements that arrive from the client. The session value of this variable is set using the character set requested by the client when the client connects to the server. (Many clients support a --default-character-set option to enable this character set to be specified explicitly. See also Section 10.1.4, “Connection Character Sets and Collations”.) The global value of the variable is used to set the session value in cases when the client-requested value is unknown or not available, or the server is configured to ignore client requests:

    • The client is from a version of MySQL older than MySQL 4.1, and thus does not request a character set.

    • The client requests a character set not known to the server. For example, a Japanese-enabled client requests sjis when connecting to a server not configured with sjis support.

    • mysqld was started with the --skip-character-set-client-handshake option, which causes it to ignore client character set configuration. This reproduces MySQL 4.0 behavior and is useful should you wish to upgrade the server without upgrading all the clients.

    ucs2 cannot be used as a client character set, which means that it also does not work for SET NAMES or SET CHARACTER SET.

  • character_set_connection

    System VariableNamecharacter_set_connection
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring

    The character set used for literals that do not have a character set introducer and for number-to-string conversion.

  • character_set_database

    System VariableNamecharacter_set_database
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    FootnoteThis option is dynamic, but only the server should set this information. You should not set the value of this variable manually.
    Permitted ValuesTypestring

    The character set used by the default database. The server sets this variable whenever the default database changes. If there is no default database, the variable has the same value as character_set_server.

  • character_set_filesystem

    Introduced5.0.19
    Command-Line Format--character-set-filesystem=name
    System VariableNamecharacter_set_filesystem
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring
    Defaultbinary

    The file system character set. This variable is used to interpret string literals that refer to file names, such as in the LOAD DATA INFILE and SELECT ... INTO OUTFILE statements and the LOAD_FILE() function. Such file names are converted from character_set_client to character_set_filesystem before the file opening attempt occurs. The default value is binary, which means that no conversion occurs. For systems on which multibyte file names are permitted, a different value may be more appropriate. For example, if the system represents file names using UTF-8, set character_set_filesystem to 'utf8'. This variable was added in MySQL 5.0.19.

  • character_set_results

    System VariableNamecharacter_set_results
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring

    The character set used for returning query results such as result sets or error messages to the client.

  • character_set_server

    Command-Line Format--character-set-server
    System VariableNamecharacter_set_server
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring
    Defaultlatin1

    The server's default character set.

  • character_set_system

    System VariableNamecharacter_set_system
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring
    Defaultutf8

    The character set used by the server for storing identifiers. The value is always utf8.

  • character_sets_dir

    Command-Line Format--character-sets-dir=dir_name
    System VariableNamecharacter_sets_dir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The directory where character sets are installed.

  • collation_connection

    System VariableNamecollation_connection
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring

    The collation of the connection character set.

  • collation_database

    System VariableNamecollation_database
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    FootnoteThis option is dynamic, but only the server should set this information. You should not set the value of this variable manually.
    Permitted ValuesTypestring

    The collation used by the default database. The server sets this variable whenever the default database changes. If there is no default database, the variable has the same value as collation_server.

  • collation_server

    Command-Line Format--collation-server
    System VariableNamecollation_server
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring
    Defaultlatin1_swedish_ci

    The server's default collation.

  • completion_type

    Introduced5.0.3
    Command-Line Format--completion_type=#
    System VariableNamecompletion_type
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (>= 5.0.3)Typeinteger
    Default0
    Valid Values0
    1
    2

    The transaction completion type. This variable can take the values shown in the following table.

    ValueDescription
    0COMMIT and ROLLBACK are unaffected. This is the default value.
    1COMMIT and ROLLBACK are equivalent to COMMIT AND CHAIN and ROLLBACK AND CHAIN, respectively. (A new transaction starts immediately with the same isolation level as the just-terminated transaction.)
    2COMMIT and ROLLBACK are equivalent to COMMIT RELEASE and ROLLBACK RELEASE, respectively. (The server disconnects after terminating the transaction.)

    completion_type affects transactions that begin with START TRANSACTION or BEGIN and end with COMMIT or ROLLBACK. It does not apply to implicit commits resulting from execution of the statements listed in Section 13.3.3, “Statements That Cause an Implicit Commit”. It also does not apply for XA COMMIT, XA ROLLBACK, or when autocommit=1.

    This variable was added in MySQL 5.0.3.

  • concurrent_insert

    Command-Line Format--concurrent_insert[=#]
    System VariableNameconcurrent_insert
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (<= 5.0.5)Typeboolean
    DefaultTRUE
    Permitted Values (>= 5.0.6)Typeinteger
    Default1
    Valid Values0
    1
    2

    If 1 (the default), MySQL permits INSERT and SELECT statements to run concurrently for MyISAM tables that have no free blocks in the middle of the data file. If you start mysqld with --skip-new, this variable is set to 0.

    In MySQL 5.0.6, this variable was changed to take three integer values:

    ValueDescription
    0Disables concurrent inserts
    1(Default) Enables concurrent insert for MyISAM tables that do not have holes
    2Enables concurrent inserts for all MyISAM tables, even those that have holes. For a table with a hole, new rows are inserted at the end of the table if it is in use by another thread. Otherwise, MySQL acquires a normal write lock and inserts the row into the hole.

    See also Section 8.11.3, “Concurrent Inserts”.

  • connect_timeout

    Command-Line Format--connect_timeout=#
    System VariableNameconnect_timeout
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (<= 5.0.51)Typeinteger
    Default5
    Min Value2
    Max Value31536000
    Permitted Values (>= 5.0.52)Typeinteger
    Default10
    Min Value2
    Max Value31536000

    The number of seconds that the mysqld server waits for a connect packet before responding with Bad handshake. The default value is 10 seconds as of MySQL 5.0.52 and 5 seconds before that.

    Increasing the connect_timeout value might help if clients frequently encounter errors of the form Lost connection to MySQL server at 'XXX', system error: errno.

  • datadir

    Command-Line Format--datadir=dir_name
    System VariableNamedatadir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The MySQL data directory. This variable can be set with the --datadir option.

  • date_format

    This variable is unused.

  • datetime_format

    This variable is unused.

  • default_week_format

    Command-Line Format--default_week_format=#
    System VariableNamedefault_week_format
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value7

    The default mode value to use for the WEEK() function. See Section 12.7, “Date and Time Functions”.

  • delay_key_write

    Command-Line Format--delay-key-write[=name]
    System VariableNamedelay_key_write
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    DefaultON
    Valid ValuesON
    OFF
    ALL

    This option applies only to MyISAM tables. It can have one of the following values to affect handling of the DELAY_KEY_WRITE table option that can be used in CREATE TABLE statements.

    OptionDescription
    OFFDELAY_KEY_WRITE is ignored.
    ONMySQL honors any DELAY_KEY_WRITE option specified in CREATE TABLE statements. This is the default value.
    ALLAll new opened tables are treated as if they were created with the DELAY_KEY_WRITE option enabled.

    If DELAY_KEY_WRITE is enabled for a table, the key buffer is not flushed for the table on every index update, but only when the table is closed. This speeds up writes on keys a lot, but if you use this feature, you should add automatic checking of all MyISAM tables by starting the server with the --myisam-recover option (for example, --myisam-recover=BACKUP,FORCE). See Section 5.1.3, “Server Command Options”, and Section 14.1.1, “MyISAM Startup Options”.

    Warning

    If you enable external locking with --external-locking, there is no protection against index corruption for tables that use delayed key writes.

  • delayed_insert_limit

    Command-Line Format--delayed_insert_limit=#
    System VariableNamedelayed_insert_limit
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default100
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default100
    Min Value1
    Max Value18446744073709547520

    After inserting delayed_insert_limit delayed rows, the INSERT DELAYED handler thread checks whether there are any SELECT statements pending. If so, it permits them to execute before continuing to insert delayed rows.

  • delayed_insert_timeout

    Command-Line Format--delayed_insert_timeout=#
    System VariableNamedelayed_insert_timeout
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default300

    How many seconds an INSERT DELAYED handler thread should wait for INSERT statements before terminating.

  • delayed_queue_size

    Command-Line Format--delayed_queue_size=#
    System VariableNamedelayed_queue_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default1000
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default1000
    Min Value1
    Max Value18446744073709547520

    This is a per-table limit on the number of rows to queue when handling INSERT DELAYED statements. If the queue becomes full, any client that issues an INSERT DELAYED statement waits until there is room in the queue again.

  • div_precision_increment

    Introduced5.0.6
    Command-Line Format--div_precision_increment=#
    System VariableNamediv_precision_increment
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default4
    Min Value0
    Max Value30

    This variable indicates the number of digits by which to increase the scale of the result of division operations performed with the / operator. The default value is 4. The minimum and maximum values are 0 and 30, respectively. The following example illustrates the effect of increasing the default value.

    mysql> SELECT 1/7;
    +--------+
    | 1/7    |
    +--------+
    | 0.1429 |
    +--------+
    mysql> SET div_precision_increment = 12;
    mysql> SELECT 1/7;
    +----------------+
    | 1/7            |
    +----------------+
    | 0.142857142857 |
    +----------------+
    

    This variable was added in MySQL 5.0.6.

  • engine_condition_pushdown

    Introduced5.0.3
    Command-Line Format--engine-condition-pushdown
    System VariableNameengine_condition_pushdown
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (>= 5.0.3)Typeboolean
    DefaultOFF

    The engine condition pushdown optimization enables processing for certain comparisons to be pushed down to the storage engine level for more efficient execution. For more information, see Section 8.2.1.5, “Engine Condition Pushdown Optimization”.

    Engine condition pushdown is used only by the NDBCLUSTER storage engine. Enabling this optimization on a MySQL Server acting as a MySQL Cluster SQL node causes WHERE conditions on unindexed columns to be evaluated on the cluster's data nodes and only the rows that match to be sent back to the SQL node that issued the query. This greatly reduces the amount of cluster data that must be sent over the network, increasing the efficiency with which results are returned.

    The engine_condition_pushdown variable controls whether engine condition pushdown is enabled. By default, this variable is OFF (0). Setting it to ON (1) enables pushdown.

    This variable was added in MySQL 5.0.3.

  • error_count

    The number of errors that resulted from the last statement that generated messages. This variable is read only. See Section 13.7.5.14, “SHOW ERRORS Syntax”.

  • expire_logs_days

    Command-Line Format--expire_logs_days=#
    System VariableNameexpire_logs_days
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value99

    The number of days for automatic binary log file removal. The default is 0, which means no automatic removal. Possible removals happen at startup and when the binary log is flushed. Log flushing occurs as indicated in Section 5.4, “MySQL Server Logs”.

    To remove binary log files manually, use the PURGE BINARY LOGS statement. See Section 13.4.1.1, “PURGE BINARY LOGS Syntax”.

  • flush

    Command-Line Format--flush
    System VariableNameflush
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    If ON, the server flushes (synchronizes) all changes to disk after each SQL statement. Normally, MySQL does a write of all changes to disk only after each SQL statement and lets the operating system handle the synchronizing to disk. See Section B.5.3.3, “What to Do If MySQL Keeps Crashing”. This variable is set to ON if you start mysqld with the --flush option.

  • flush_time

    Command-Line Format--flush_time=#
    System VariableNameflush_time
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Permitted Values (Windows)Typeinteger
    Default1800
    Min Value0

    If this is set to a nonzero value, all tables are closed every flush_time seconds to free up resources and synchronize unflushed data to disk. This option is best used only on systems with minimal resources.

  • foreign_key_checks

    If set to 1 (the default), foreign key constraints for InnoDB tables are checked. If set to 0, foreign key constraints are ignored, with a couple of exceptions. When re-creating a table that was dropped, an error is returned if the table definition does not conform to the foreign key constraints referencing the table. Likewise, an ALTER TABLE operation returns an error if a foreign key definition is incorrectly formed. For more information, see Section 13.1.10.3, “Using FOREIGN KEY Constraints”.

    Disabling foreign key checking can be useful for reloading InnoDB tables in an order different from that required by their parent/child relationships. See Section 14.2.3.4, “InnoDB and FOREIGN KEY Constraints”.

    Setting foreign_key_checks to 0 also affects data definition statements: DROP DATABASE drops a database even if it contains tables that have foreign keys that are referred to by tables outside the database, and DROP TABLE drops tables that have foreign keys that are referred to by other tables.

    Note

    Setting foreign_key_checks to 1 does not trigger a scan of the existing table data. Therefore, rows added to the table while foreign_key_checks = 0 will not be verified for consistency.

  • ft_boolean_syntax

    Command-Line Format--ft_boolean_syntax=name
    System VariableNameft_boolean_syntax
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypestring
    Default+ -><()~*:""&|

    The list of operators supported by boolean full-text searches performed using IN BOOLEAN MODE. See Section 12.9.2, “Boolean Full-Text Searches”.

    The default variable value is '+ -><()~*:""&|'. The rules for changing the value are as follows:

    • Operator function is determined by position within the string.

    • The replacement value must be 14 characters.

    • Each character must be an ASCII nonalphanumeric character.

    • Either the first or second character must be a space.

    • No duplicates are permitted except the phrase quoting operators in positions 11 and 12. These two characters are not required to be the same, but they are the only two that may be.

    • Positions 10, 13, and 14 (which by default are set to :, &, and |) are reserved for future extensions.

  • ft_max_word_len

    Command-Line Format--ft_max_word_len=#
    System VariableNameft_max_word_len
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Min Value10

    The maximum length of the word to be included in a FULLTEXT index.

    Note

    FULLTEXT indexes must be rebuilt after changing this variable. Use REPAIR TABLE tbl_name QUICK.

  • ft_min_word_len

    Command-Line Format--ft_min_word_len=#
    System VariableNameft_min_word_len
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default4
    Min Value1

    The minimum length of the word to be included in a FULLTEXT index.

    Note

    FULLTEXT indexes must be rebuilt after changing this variable. Use REPAIR TABLE tbl_name QUICK.

  • ft_query_expansion_limit

    Command-Line Format--ft_query_expansion_limit=#
    System VariableNameft_query_expansion_limit
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default20
    Min Value0
    Max Value1000

    The number of top matches to use for full-text searches performed using WITH QUERY EXPANSION.

  • ft_stopword_file

    Command-Line Format--ft_stopword_file=file_name
    System VariableNameft_stopword_file
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The file from which to read the list of stopwords for full-text searches. The server looks for the file in the data directory unless an absolute path name is given to specify a different directory. All the words from the file are used; comments are not honored. By default, a built-in list of stopwords is used (as defined in the myisam/ft_static.c file). Setting this variable to the empty string ('') disables stopword filtering. See also Section 12.9.4, “Full-Text Stopwords”.

    Note

    FULLTEXT indexes must be rebuilt after changing this variable or the contents of the stopword file. Use REPAIR TABLE tbl_name QUICK.

  • group_concat_max_len

    Command-Line Format--group_concat_max_len=#
    System VariableNamegroup_concat_max_len
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default1024
    Min Value4
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default1024
    Min Value4
    Max Value18446744073709547520

    The maximum permitted result length in bytes for the GROUP_CONCAT() function. The default is 1024.

  • have_archive

    YES if mysqld supports ARCHIVE tables, NO if not.

  • have_bdb

    YES if mysqld supports BDB tables. DISABLED if --skip-bdb is used.

  • have_blackhole_engine

    YES if mysqld supports BLACKHOLE tables, NO if not.

  • have_community_features

    YES if statement profiling capability is present, NO if not. If present, the profiling system variable controls whether this capability is enabled or disabled. See Section 13.7.5.29, “SHOW PROFILES Syntax”.

    This variable was added in MySQL 5.0.82.

  • have_compress

    YES if the zlib compression library is available to the server, NO if not. If not, the COMPRESS() and UNCOMPRESS() functions cannot be used.

  • have_crypt

    YES if the crypt() system call is available to the server, NO if not. If not, the ENCRYPT() function cannot be used.

  • have_csv

    YES if mysqld supports CSV tables, NO if not.

  • have_example_engine

    YES if mysqld supports EXAMPLE tables, NO if not.

  • have_federated_engine

    YES if mysqld supports FEDERATED tables, NO if not. This variable was added in MySQL 5.0.3.

  • have_geometry

    YES if the server supports spatial data types, NO if not.

  • have_innodb

    YES if mysqld supports InnoDB tables. DISABLED if --skip-innodb is used.

  • have_isam

    This variable appears only for reasons of backward compatibility. It is always NO because ISAM tables are no longer supported.

  • have_merge_engine

    YES if mysqld supports MERGE tables. DISABLED if --skip-merge is used. This variable was added in MySQL 5.0.24.

  • have_openssl

    YES if mysqld supports SSL connections, NO if not. As of MySQL 5.0.38, this variable is an alias for have_ssl.

  • have_profiling

    YES if statement profiling capability is present, NO if not. If present, the profiling system variable controls whether this capability is enabled or disabled. See Section 13.7.5.29, “SHOW PROFILES Syntax”.

    This variable was added in MySQL 5.0.82.

  • have_query_cache

    YES if mysqld supports the query cache, NO if not.

  • have_raid

    This variable appears only for reasons of backward compatibility. It is always NO because RAID tables are no longer supported.

  • have_rtree_keys

    YES if RTREE indexes are available, NO if not. (These are used for spatial indexes in MyISAM tables.)

  • have_ssl

    YES if mysqld supports SSL connections, NO if not. DISABLED indicates that the server was compiled with SSL support, but but was not started with the appropriate --ssl-xxx options. For more information, see Section 6.3.6.2, “Building MySQL with Support for Secure Connections”.

    This variable was added in MySQL 5.0.38. Before that, use have_openssl.

  • have_symlink

    YES if symbolic link support is enabled, NO if not. This is required on Unix for support of the DATA DIRECTORY and INDEX DIRECTORY table options, and on Windows for support of data directory symlinks. If the server is started with the --skip-symbolic-links option, the value is DISABLED.

  • hostname

    Introduced5.0.38
    System VariableNamehostname
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring

    The server sets this variable to the server host name at startup. This variable was added in MySQL 5.0.38.

  • identity

    This variable is a synonym for the last_insert_id variable. It exists for compatibility with other database systems. You can read its value with SELECT @@identity, and set it using SET identity.

  • init_connect

    Command-Line Format--init-connect=name
    System VariableNameinit_connect
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypestring

    A string to be executed by the server for each client that connects. The string consists of one or more SQL statements, separated by semicolon characters. For example, each client session begins by default with autocommit mode enabled. There is no global autocommit system variable to specify that autocommit should be disabled by default, but init_connect can be used to achieve the same effect:

    SET GLOBAL init_connect='SET autocommit=0';
    

    The init_connect variable can also be set on the command line or in an option file. To set the variable as just shown using an option file, include these lines:

    [mysqld]
    init_connect='SET autocommit=0'
    

    The content of init_connect is not executed for users that have the SUPER privilege. This is done so that an erroneous value for init_connect does not prevent all clients from connecting. For example, the value might contain a statement that has a syntax error, thus causing client connections to fail. Not executing init_connect for users that have the SUPER privilege enables them to open a connection and fix the init_connect value.

    The server discards any result sets produced by statements in the value of of init_connect.

  • init_file

    Command-Line Format--init-file=file_name
    System VariableNameinit_file
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The name of the file specified with the --init-file option when you start the server. This should be a file containing SQL statements that you want the server to execute when it starts. Each statement must be on a single line and should not include comments. For more information, see the description of --init-file.

    Note that the --init-file option is unavailable if MySQL was configured with the --disable-grant-options option. See Section 2.17.3, “MySQL Source-Configuration Options”.

  • innodb_xxx

    InnoDB system variables are listed in Section 14.2.2, “InnoDB Startup Options and System Variables”.

  • insert_id

    The value to be used by the following INSERT or ALTER TABLE statement when inserting an AUTO_INCREMENT value. This is mainly used with the binary log.

  • interactive_timeout

    Command-Line Format--interactive_timeout=#
    System VariableNameinteractive_timeout
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default28800
    Min Value1

    The number of seconds the server waits for activity on an interactive connection before closing it. An interactive client is defined as a client that uses the CLIENT_INTERACTIVE option to mysql_real_connect(). See also wait_timeout.

  • join_buffer_size

    Command-Line Format--join_buffer_size=#
    System VariableNamejoin_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default131072
    Min Value8200
    Max Value4294967295

    The minimum size of the buffer that is used for plain index scans, range index scans, and joins that do not use indexes and thus perform full table scans. Normally, the best way to get fast joins is to add indexes. Increase the value of join_buffer_size to get a faster full join when adding indexes is not possible. One join buffer is allocated for each full join between two tables. For a complex join between several tables for which indexes are not used, multiple join buffers might be necessary.

    There is no gain from setting the buffer larger than required to hold each matching row, and all joins allocate at least the minimum size, so use caution in setting this variable to a large value globally. It is better to keep the global setting small and change to a larger setting only in sessions that are doing large joins. Memory allocation time can cause substantial performance drops if the global size is larger than needed by most queries that use it.

    The maximum permissible setting for join_buffer_size is 4GB−1.

    For additional information about join buffering, see Section 8.2.1.8, “Nested-Loop Join Algorithms”.

  • keep_files_on_create

    Introduced5.0.48
    Command-Line Format--keep_files_on_create=#
    System VariableNamekeep_files_on_create
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    If a MyISAM table is created with no DATA DIRECTORY option, the .MYD file is created in the database directory. By default, if MyISAM finds an existing .MYD file in this case, it overwrites it. The same applies to .MYI files for tables created with no INDEX DIRECTORY option. To suppress this behavior, set the keep_files_on_create variable to ON (1), in which case MyISAM will not overwrite existing files and returns an error instead. The default value is OFF (0).

    If a MyISAM table is created with a DATA DIRECTORY or INDEX DIRECTORY option and an existing .MYD or .MYI file is found, MyISAM always returns an error. It will not overwrite a file in the specified directory.

    This variable was added in MySQL 5.0.48.

  • key_buffer_size

    Command-Line Format--key_buffer_size=#
    System VariableNamekey_buffer_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default8388608
    Min Value8
    Max Value4294967295

    Index blocks for MyISAM tables are buffered and are shared by all threads. key_buffer_size is the size of the buffer used for index blocks. The key buffer is also known as the key cache.

    The maximum permissible setting for key_buffer_size is 4GB−1 on 32-bit platforms. As of MySQL 5.0.52, larger values are permitted for 64-bit platforms (except 64-bit Windows, for which large values are truncated to 4GB−1 with a warning). The effective maximum size might be less, depending on your available physical RAM and per-process RAM limits imposed by your operating system or hardware platform. The value of this variable indicates the amount of memory requested. Internally, the server allocates as much memory as possible up to this amount, but the actual allocation might be less.

    You can increase the value to get better index handling for all reads and multiple writes; on a system whose primary function is to run MySQL using the MyISAM storage engine, 25% of the machine's total memory is an acceptable value for this variable. However, you should be aware that, if you make the value too large (for example, more than 50% of the machine's total memory), your system might start to page and become extremely slow. This is because MySQL relies on the operating system to perform file system caching for data reads, so you must leave some room for the file system cache. You should also consider the memory requirements of any other storage engines that you may be using in addition to MyISAM.

    For even more speed when writing many rows at the same time, use LOCK TABLES. See Section 8.2.2.1, “Speed of INSERT Statements”.

    You can check the performance of the key buffer by issuing a SHOW STATUS statement and examining the Key_read_requests, Key_reads, Key_write_requests, and Key_writes status variables. (See Section 13.7.5, “SHOW Syntax”.) The Key_reads/Key_read_requests ratio should normally be less than 0.01. The Key_writes/Key_write_requests ratio is usually near 1 if you are using mostly updates and deletes, but might be much smaller if you tend to do updates that affect many rows at the same time or if you are using the DELAY_KEY_WRITE table option.

    The fraction of the key buffer in use can be determined using key_buffer_size in conjunction with the Key_blocks_unused status variable and the buffer block size, which is available from the key_cache_block_size system variable:

    1 - ((Key_blocks_unused * key_cache_block_size) / key_buffer_size)
    

    This value is an approximation because some space in the key buffer is allocated internally for administrative structures. Factors that influence the amount of overhead for these structures include block size and pointer size. As block size increases, the percentage of the key buffer lost to overhead tends to decrease. Larger blocks results in a smaller number of read operations (because more keys are obtained per read), but conversely an increase in reads of keys that are not examined (if not all keys in a block are relevant to a query).

    It is possible to create multiple MyISAM key caches. The size limit of 4GB applies to each cache individually, not as a group. See Section 8.10.1, “The MyISAM Key Cache”.

  • key_cache_age_threshold

    Command-Line Format--key_cache_age_threshold=#
    System VariableNamekey_cache_age_threshold
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default300
    Min Value100
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default300
    Min Value100
    Max Value18446744073709547520

    This value controls the demotion of buffers from the hot sublist of a key cache to the warm sublist. Lower values cause demotion to happen more quickly. The minimum value is 100. The default value is 300. See Section 8.10.1, “The MyISAM Key Cache”.

  • key_cache_block_size

    Command-Line Format--key_cache_block_size=#
    System VariableNamekey_cache_block_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default1024
    Min Value512
    Max Value16384

    The size in bytes of blocks in the key cache. The default value is 1024. See Section 8.10.1, “The MyISAM Key Cache”.

  • key_cache_division_limit

    Command-Line Format--key_cache_division_limit=#
    System VariableNamekey_cache_division_limit
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default100
    Min Value1
    Max Value100

    The division point between the hot and warm sublists of the key cache buffer list. The value is the percentage of the buffer list to use for the warm sublist. Permissible values range from 1 to 100. The default value is 100. See Section 8.10.1, “The MyISAM Key Cache”.

  • language

    Command-Line Format--language=name
    System VariableNamelanguage
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name
    Default/usr/local/mysql/share/mysql/english/

    The directory where error messages are located. See Section 10.2, “Setting the Error Message Language”.

  • large_files_support

    System VariableNamelarge_files_support
    Variable ScopeGlobal
    Dynamic VariableNo

    Whether mysqld was compiled with options for large file support.

  • large_pages

    Introduced5.0.3
    Command-Line Format--large-pages
    System VariableNamelarge_pages
    Variable ScopeGlobal
    Dynamic VariableNo
    Platform SpecificLinux
    Permitted Values (Linux)Typeboolean
    DefaultFALSE

    Whether large page support is enabled (via the --large-pages option). See Section 8.12.5.2, “Enabling Large Page Support”. This variable was added in MySQL 5.0.3.

    For more information, see the entry for the --large-pages server option.

  • large_page_size

    Introduced5.0.3
    System VariableNamelarge_page_size
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted Values (Linux)Typeinteger
    Default0

    If large page support is enabled, this shows the size of memory pages. Large memory pages are supported only on Linux; on other platforms, the value of this variable is always 0. This variable was added in MySQL 5.0.3.

    For more information, see the entry for the --large-pages server option.

  • last_insert_id

    The value to be returned from LAST_INSERT_ID(). This is stored in the binary log when you use LAST_INSERT_ID() in a statement that updates a table. Setting this variable does not update the value returned by the mysql_insert_id() C API function.

  • lc_time_names

    Introduced5.0.25
    System VariableNamelc_time_names
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring

    This variable specifies the locale that controls the language used to display day and month names and abbreviations. This variable affects the output from the DATE_FORMAT(), DAYNAME() and MONTHNAME() functions. Locale names are POSIX-style values such as 'ja_JP' or 'pt_BR'. The default value is 'en_US' regardless of your system's locale setting. For further information, see Section 10.7, “MySQL Server Locale Support”. This variable was added in MySQL 5.0.25.

  • license

    System VariableNamelicense
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring
    DefaultGPL

    The type of license the server has.

  • local_infile

    System VariableNamelocal_infile
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean

    Whether LOCAL is supported for LOAD DATA INFILE statements. If this variable is disabled, clients cannot use LOCAL in LOAD DATA statements. See Section 6.1.6, “Security Issues with LOAD DATA LOCAL”.

  • locked_in_memory

    System VariableNamelocked_in_memory
    Variable ScopeGlobal
    Dynamic VariableNo

    Whether mysqld was locked in memory with --memlock.

  • log

    Command-Line Format--log[=file_name]
    System VariableNamelog
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    Whether logging of all statements to the general query log is enabled. See Section 5.4.2, “The General Query Log”.

  • log_bin_trust_function_creators

    Introduced5.0.16
    Command-Line Format--log-bin-trust-function-creators
    System VariableNamelog_bin_trust_function_creators
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultFALSE

    This variable applies when binary logging is enabled. It controls whether stored function creators can be trusted not to create stored functions that will cause unsafe events to be written to the binary log. If set to 0 (the default), users are not permitted to create or alter stored functions unless they have the SUPER privilege in addition to the CREATE ROUTINE or ALTER ROUTINE privilege. A setting of 0 also enforces the restriction that a function must be declared with the DETERMINISTIC characteristic, or with the READS SQL DATA or NO SQL characteristic. If the variable is set to 1, MySQL does not enforce these restrictions on stored function creation. This variable also applies to trigger creation. See Section 18.6, “Binary Logging of Stored Programs”.

    This variable was added in MySQL 5.0.16.

  • log_bin_trust_routine_creators

    This is the old name for log_bin_trust_function_creators. Before MySQL 5.0.16, it also applies to stored procedures, not just stored functions. As of 5.0.16, this variable is deprecated. It is recognized for backward compatibility but its use results in a warning.

    This variable was added in MySQL 5.0.6. It is removed in MySQL 5.5.

  • log_error

    Command-Line Format--log-error[=file_name]
    System VariableNamelog_error
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The location of the error log, or empty if the server is writing error message to the standard error output. See Section 5.4.1, “The Error Log”.

  • log_queries_not_using_indexes

    Command-Line Format--log-queries-not-using-indexes
    System Variable (>= 5.0.23)Namelog_queries_not_using_indexes
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    Whether queries that do not use indexes are logged to the slow query log. See Section 5.4.4, “The Slow Query Log”. This variable was added in MySQL 5.0.23.

  • log_slow_queries

    Command-Line Format--log-slow-queries[=name]
    System VariableNamelog_slow_queries
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeboolean

    Whether slow queries should be logged. Slow is determined by the value of the long_query_time variable. See Section 5.4.4, “The Slow Query Log”.

  • log_warnings

    Command-Line Format--log-warnings[=#]
    System VariableNamelog_warnings
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default1
    Min Value0
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default1
    Min Value0
    Max Value18446744073709547520

    Whether to produce additional warning messages to the error log. This variable is enabled (1) by default and can be disabled by setting it to 0. Aborted connections and access-denied errors for new connection attempts are logged if the value is greater than 1.

  • long_query_time

    Command-Line Format--long_query_time=#
    System VariableNamelong_query_time
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (<= 5.0.20)Typeinteger
    Default10
    Min Value1
    Permitted Values (>= 5.0.21)Typenumeric
    Default10
    Min Value0

    If a query takes longer than this many seconds, the server increments the Slow_queries status variable. If you are using the --log-slow-queries option, the query is logged to the slow query log file. This value is measured in real time, not CPU time, so a query that is under the threshold on a lightly loaded system might be above the threshold on a heavily loaded one. The minimum value is 1. The default is 10. See Section 5.4.4, “The Slow Query Log”.

  • low_priority_updates

    Command-Line Format--low-priority-updates
    System VariableNamelow_priority_updates
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultFALSE

    If set to 1, all INSERT, UPDATE, DELETE, and LOCK TABLE WRITE statements wait until there is no pending SELECT or LOCK TABLE READ on the affected table. This affects only storage engines that use only table-level locking (such as MyISAM, MEMORY, and MERGE). This variable previously was named sql_low_priority_updates.

  • lower_case_file_system

    System VariableNamelower_case_file_system
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeboolean

    This variable describes the case sensitivity of file names on the file system where the data directory is located. OFF means file names are case sensitive, ON means they are not case sensitive. This variable is read only because it reflects a file system attribute and setting it would have no effect on the file system.

  • lower_case_table_names

    Command-Line Format--lower_case_table_names[=#]
    System VariableNamelower_case_table_names
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value2

    If set to 0, table names are stored as specified and comparisons are case sensitive. If set to 1, table names are stored in lowercase on disk and comparisons are not case sensitive. If set to 2, table names are stored as given but compared in lowercase. This option also applies to database names and table aliases. For additional information, see Section 9.2.2, “Identifier Case Sensitivity”.

    On Windows the default value is 1. On OS X, the default value is 2.

    You should not set lower_case_table_names to 0 if you are running MySQL on a system where the data directory resides on a case-insensitive file system (such as on Windows or OS X). It is an unsupported combination that could result in a hang condition when running an INSERT INTO ... SELECT ... FROM tbl_name operation with the wrong tbl_name letter case. With MyISAM, accessing table names using different letter cases could cause index corruption.

    If you are using InnoDB or MySQL Cluster (NDB) tables, you should set this variable to 1 on all platforms to force names to be converted to lowercase.

    The setting of this variable has no effect on replication filtering options. See Section 16.2.3, “How Servers Evaluate Replication Filtering Rules”, for more information.

    You should not use different settings for lower_case_table_names on replication masters and slaves. In particular, you should not do this when the slave uses a case-sensitive file system, as this can cause replication to fail. For more information, see Section 16.4.1.29, “Replication and Variables”.

  • max_allowed_packet

    Command-Line Format--max_allowed_packet=#
    System VariableNamemax_allowed_packet
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default1048576
    Min Value1024
    Max Value1073741824

    The maximum size of one packet or any generated/intermediate string.

    The packet message buffer is initialized to net_buffer_length bytes, but can grow up to max_allowed_packet bytes when needed. This value by default is small, to catch large (possibly incorrect) packets.

    You must increase this value if you are using large BLOB columns or long strings. It should be as big as the largest BLOB you want to use. The protocol limit for max_allowed_packet is 1GB. The value should be a multiple of 1024; nonmultiples are rounded down to the nearest multiple.

    When you change the message buffer size by changing the value of the max_allowed_packet variable, you should also change the buffer size on the client side if your client program permits it. The default max_allowed_packet value built in to the client library is 1GB, but individual client programs might override this. For example, mysql and mysqldump have defaults of 16MB and 24MB, respectively. They also enable you to change the client-side value by setting max_allowed_packet on the command line or in an option file.

    As of MySQL 5.0.84, the session value of this variable is read only. Before 5.0.84, setting the session value is permitted but has no effect. The client can receive up to as many bytes as the session value. However, the server will not send to the client more bytes than the current global max_allowed_packet value. (The global value could be less than the session value if the global value is changed after the client connects.)

  • max_connect_errors

    Command-Line Format--max_connect_errors=#
    System VariableNamemax_connect_errors
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default10
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default10
    Min Value1
    Max Value18446744073709547520

    If more than this many successive connection requests from a host are interrupted without a successful connection, the server blocks that host from further connections. You can unblock blocked hosts by flushing the host cache. To do so, issue a FLUSH HOSTS statement or execute a mysqladmin flush-hosts command. If a connection is established successfully within fewer than max_connect_errors attempts after a previous connection was interrupted, the error count for the host is cleared to zero. However, once a host is blocked, flushing the host cache is the only way to unblock it.

  • max_connections

    Command-Line Format--max_connections=#
    System VariableNamemax_connections
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default100
    Min Value1
    Max Value16384

    The maximum permitted number of simultaneous client connections. By default, this is 100. See Section B.5.2.7, “Too many connections”, for more information.

    Increasing this value increases the number of file descriptors that mysqld requires. See Section 8.4.3.1, “How MySQL Opens and Closes Tables”, for comments on file descriptor limits.

  • max_delayed_threads

    Command-Line Format--max_delayed_threads=#
    System VariableNamemax_delayed_threads
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default20
    Min Value0
    Max Value16384

    Do not start more than this number of threads to handle INSERT DELAYED statements. If you try to insert data into a new table after all INSERT DELAYED threads are in use, the row is inserted as if the DELAYED attribute was not specified. If you set this to 0, MySQL never creates a thread to handle DELAYED rows; in effect, this disables DELAYED entirely.

    For the SESSION value of this variable, the only valid values are 0 or the GLOBAL value.

  • max_error_count

    Command-Line Format--max_error_count=#
    System VariableNamemax_error_count
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default64
    Min Value0
    Max Value65535

    The maximum number of error, warning, and note messages to be stored for display by the SHOW ERRORS and SHOW WARNINGS statements.

  • max_heap_table_size

    Command-Line Format--max_heap_table_size=#
    System VariableNamemax_heap_table_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default16777216
    Min Value16384
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default16777216
    Min Value16384
    Max Value1844674407370954752

    This variable sets the maximum size to which user-created MEMORY tables are permitted to grow. The value of the variable is used to calculate MEMORY table MAX_ROWS values. Setting this variable has no effect on any existing MEMORY table, unless the table is re-created with a statement such as CREATE TABLE or altered with ALTER TABLE or TRUNCATE TABLE. A server restart also sets the maximum size of existing MEMORY tables to the global max_heap_table_size value.

    This variable is also used in conjunction with tmp_table_size to limit the size of internal in-memory tables. See Section 8.4.4, “Internal Temporary Table Use in MySQL”.

    max_heap_table_size is not replicated. See Section 16.4.1.15, “Replication and MEMORY Tables”, and Section 16.4.1.29, “Replication and Variables”, for more information.

  • max_insert_delayed_threads

    System VariableNamemax_insert_delayed_threads
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger

    This variable is a synonym for max_delayed_threads.

  • max_join_size

    Command-Line Format--max_join_size=#
    System VariableNamemax_join_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default4294967295
    Min Value1
    Max Value4294967295

    Do not permit statements that probably need to examine more than max_join_size rows (for single-table statements) or row combinations (for multiple-table statements) or that are likely to do more than max_join_size disk seeks. By setting this value, you can catch statements where keys are not used properly and that would probably take a long time. Set it if your users tend to perform joins that lack a WHERE clause, that take a long time, or that return millions of rows.

    Setting this variable to a value other than DEFAULT resets the value of sql_big_selects to 0. If you set the sql_big_selects value again, the max_join_size variable is ignored.

    If a query result is in the query cache, no result size check is performed, because the result has previously been computed and it does not burden the server to send it to the client.

    This variable previously was named sql_max_join_size.

  • max_length_for_sort_data

    Command-Line Format--max_length_for_sort_data=#
    System VariableNamemax_length_for_sort_data
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default1024
    Min Value4
    Max Value8388608

    The cutoff on the size of index values that determines which filesort algorithm to use. See Section 8.2.1.11, “ORDER BY Optimization”.

  • max_prepared_stmt_count

    Introduced5.0.21
    Command-Line Format--max_prepared_stmt_count=# (>= 5.0.21)
    System VariableNamemax_prepared_stmt_count
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default16382
    Min Value0
    Max Value1048576

    This variable limits the total number of prepared statements in the server. (The sum of the number of prepared statements across all sessions.) It can be used in environments where there is the potential for denial-of-service attacks based on running the server out of memory by preparing huge numbers of statements. If the value is set lower than the current number of prepared statements, existing statements are not affected and can be used, but no new statements can be prepared until the current number drops below the limit. The default value is 16,382. The permissible range of values is from 0 to 1 million. Setting the value to 0 disables prepared statements. This variable was added in MySQL 5.0.21.

  • max_relay_log_size

    Command-Line Format--max_relay_log_size=#
    System VariableNamemax_relay_log_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value1073741824

    If a write by a replication slave to its relay log causes the current log file size to exceed the value of this variable, the slave rotates the relay logs (closes the current file and opens the next one). If max_relay_log_size is 0, the server uses max_binlog_size for both the binary log and the relay log. If max_relay_log_size is greater than 0, it constrains the size of the relay log, which enables you to have different sizes for the two logs. You must set max_relay_log_size to between 4096 bytes and 1GB (inclusive), or to 0. The default value is 0. See Section 16.2.1, “Replication Implementation Details”.

  • max_seeks_for_key

    Command-Line Format--max_seeks_for_key=#
    System VariableNamemax_seeks_for_key
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default4294967295
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default18446744073709547520
    Min Value1
    Max Value18446744073709547520

    Limit the assumed maximum number of seeks when looking up rows based on a key. The MySQL optimizer assumes that no more than this number of key seeks are required when searching for matching rows in a table by scanning an index, regardless of the actual cardinality of the index (see Section 13.7.5.18, “SHOW INDEX Syntax”). By setting this to a low value (say, 100), you can force MySQL to prefer indexes instead of table scans.

  • max_sort_length

    Command-Line Format--max_sort_length=#
    System VariableNamemax_sort_length
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default1024
    Min Value4
    Max Value8388608

    The number of bytes to use when sorting data values. The server uses only the first max_sort_length bytes of each value and ignores the rest. Consequently, values that differ only after the first max_sort_length bytes compare as equal for GROUP BY, ORDER BY, and DISTINCT operations.

  • max_sp_recursion_depth

    Introduced5.0.17
    Command-Line Format--max_sp_recursion_depth[=#]
    System VariableNamemax_sp_recursion_depth
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Max Value255

    The number of times that any given stored procedure may be called recursively. The default value for this option is 0, which completely disables recursion in stored procedures. The maximum value is 255.

    Stored procedure recursion increases the demand on thread stack space. If you increase the value of max_sp_recursion_depth, it may be necessary to increase thread stack size by increasing the value of thread_stack at server startup.

    This variable was added in MySQL 5.0.17.

  • max_tmp_tables

    This variable is unused.

  • max_user_connections

    Command-Line Format--max_user_connections=#
    System Variable (<= 5.0.3)Namemax_user_connections
    Variable ScopeGlobal
    Dynamic VariableYes
    System Variable (>= 5.0.3)Namemax_user_connections
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value4294967295

    The maximum number of simultaneous connections permitted to any given MySQL user account. A value of 0 (the default) means no limit.

    Before MySQL 5.0.3, this variable has only a global value that can be set at server startup or runtime. As of MySQL 5.0.3, it also has a read-only session value that indicates the effective simultaneous-connection limit that applies to the account associated with the current session. The session value is initialized as follows:

    • If the user account has a nonzero MAX_USER_CONNECTIONS resource limit, the session max_user_connections value is set to that limit.

    • Otherwise, the session max_user_connections value is set to the global value.

    Account resource limits are specified using the GRANT statement. See Section 6.3.4, “Setting Account Resource Limits”, and Section 13.7.1.3, “GRANT Syntax”.

  • max_write_lock_count

    Command-Line Format--max_write_lock_count=#
    System VariableNamemax_write_lock_count
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default4294967295
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default18446744073709547520
    Min Value1
    Max Value18446744073709547520

    After this many write locks, permit some pending read lock requests to be processed in between.

  • multi_range_count

    Introduced5.0.3
    Command-Line Format--multi_range_count=#
    System VariableNamemulti_range_count
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default256
    Min Value1
    Max Value4294967295

    The maximum number of ranges to send to a table handler at once during range selects. The default value is 256. Sending multiple ranges to a handler at once can improve the performance of certain selects dramatically. This is especially true for the NDBCLUSTER table handler, which needs to send the range requests to all nodes. Sending a batch of those requests at once reduces communication costs significantly.

    This variable was added in MySQL 5.0.3.

  • myisam_data_pointer_size

    Command-Line Format--myisam_data_pointer_size=#
    System VariableNamemyisam_data_pointer_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (<= 5.0.5)Typeinteger
    Default4
    Min Value2
    Max Value8
    Permitted Values (>= 5.0.6)Typeinteger
    Default6
    Min Value2
    Max Value7

    The default pointer size in bytes, to be used by CREATE TABLE for MyISAM tables when no MAX_ROWS option is specified. This variable cannot be less than 2 or larger than 7. The default value is 6 (4 before MySQL 5.0.6). See Section B.5.2.12, “The table is full”.

  • myisam_max_extra_sort_file_size (DEPRECATED)

    This variable is unused as of MySQL 5.0.6.

  • myisam_max_sort_file_size

    Command-Line Format--myisam_max_sort_file_size=#
    System VariableNamemyisam_max_sort_file_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default2147483648
    Permitted Values (64-bit platforms)Typeinteger
    Default9223372036854775807

    The maximum size of the temporary file that MySQL is permitted to use while re-creating a MyISAM index (during REPAIR TABLE, ALTER TABLE, or LOAD DATA INFILE). If the file size would be larger than this value, the index is created using the key cache instead, which is slower. The value is given in bytes.

    If MyISAM index files exceed this size and disk space is available, increasing the value may help performance. The space must be available in the file system containing the directory where the original index file is located.

  • myisam_mmap_size

    Introduced5.0.90
    Command-Line Format--myisam_mmap_size=#
    System VariableNamemyisam_mmap_size
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default4294967295
    Min Value7
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default18446744073709547520
    Min Value7
    Max Value18446744073709547520

    The maximum amount of memory to use for memory mapping compressed MyISAM files. If many compressed MyISAM tables are used, the value can be decreased to reduce the likelihood of memory-swapping problems. This variable was added in MySQL 5.0.90.

  • myisam_recover_options

    System VariableNamemyisam_recover_options
    Variable ScopeGlobal
    Dynamic VariableNo

    The value of the --myisam-recover option. See Section 5.1.3, “Server Command Options”.

  • myisam_repair_threads

    Command-Line Format--myisam_repair_threads=#
    System VariableNamemyisam_repair_threads
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default1
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default1
    Min Value1
    Max Value18446744073709547520

    If this value is greater than 1, MyISAM table indexes are created in parallel (each index in its own thread) during the Repair by sorting process. The default value is 1.

    Note

    Multi-threaded repair is still beta-quality code.

  • myisam_sort_buffer_size

    Command-Line Format--myisam_sort_buffer_size=#
    System VariableNamemyisam_sort_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (Windows)Typeinteger
    Default8388608
    Min Value4096
    Max Value4294967295
    Permitted Values (Other, 32-bit platforms)Typeinteger
    Default8388608
    Min Value4096
    Max Value4294967295
    Permitted Values (Other, 64-bit platforms)Typeinteger
    Default8388608
    Min Value4096
    Max Value18446744073709547520

    The size of the buffer that is allocated when sorting MyISAM indexes during a REPAIR TABLE or when creating indexes with CREATE INDEX or ALTER TABLE.

    The maximum permissible setting for myisam_sort_buffer_size is 4GB−1.

  • myisam_stats_method

    Introduced5.0.14
    Command-Line Format--myisam_stats_method=name
    System VariableNamemyisam_stats_method
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (>= 5.0.14)Typeenumeration
    Defaultnulls_unequal
    Valid Valuesnulls_equal
    nulls_unequal
    nulls_ignored

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

    The method that is used for generating table statistics influences how the optimizer chooses indexes for query execution, as described in Section 8.3.7, “MyISAM Index Statistics Collection”.

    Any unique prefix of a valid value may be used to set the value of this variable.

    This variable was added in MySQL 5.0.14. For older versions, the statistics collection method is equivalent to nulls_equal.

  • named_pipe

    System VariableNamenamed_pipe
    Variable ScopeGlobal
    Dynamic VariableNo
    Platform SpecificWindows
    Permitted Values (Windows)Typeboolean
    DefaultOFF

    (Windows only.) Indicates whether the server supports connections over named pipes.

  • net_buffer_length

    Command-Line Format--net_buffer_length=#
    System VariableNamenet_buffer_length
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default16384
    Min Value1024
    Max Value1048576

    Each client thread is associated with a connection buffer and result buffer. Both begin with a size given by net_buffer_length but are dynamically enlarged up to max_allowed_packet bytes as needed. The result buffer shrinks to net_buffer_length after each SQL statement.

    This variable should not normally be changed, but if you have very little memory, you can set it to the expected length of statements sent by clients. If statements exceed this length, the connection buffer is automatically enlarged. The maximum value to which net_buffer_length can be set is 1MB.

    As of MySQL 5.0.84, the session value of this variable is read only. Before 5.0.84, setting the session value is permitted but has no effect.

  • net_read_timeout

    Command-Line Format--net_read_timeout=#
    System VariableNamenet_read_timeout
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default30
    Min Value1

    The number of seconds to wait for more data from a connection before aborting the read. This timeout applies only to TCP/IP connections, not to connections made through Unix socket files, named pipes, or shared memory. When the server is reading from the client, net_read_timeout is the timeout value controlling when to abort. When the server is writing to the client, net_write_timeout is the timeout value controlling when to abort. See also slave_net_timeout.

    On Linux, the NO_ALARM build flag affects timeout behavior as indicated in the description of the net_retry_count system variable.

  • net_retry_count

    Command-Line Format--net_retry_count=#
    System VariableNamenet_retry_count
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default10
    Min Value1
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default10
    Min Value1
    Max Value18446744073709547520

    If a read or write on a communication port is interrupted, retry this many times before giving up. This value should be set quite high on FreeBSD because internal interrupts are sent to all threads.

    On Linux, the NO_ALARM build flag (-DNO_ALARM) modifies how the binary treats both net_read_timeout and net_write_timeout. With this flag enabled, neither timer cancels the current statement until after the failing connection has been waited on an additional net_retry_count times. This means that the effective timeout value becomes (timeout setting) × (net_retry_count+1).

  • net_write_timeout

    Command-Line Format--net_write_timeout=#
    System VariableNamenet_write_timeout
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default60
    Min Value1

    The number of seconds to wait for a block to be written to a connection before aborting the write. This timeout applies only to TCP/IP connections, not to connections made using Unix socket files, named pipes, or shared memory. See also net_read_timeout.

    On Linux, the NO_ALARM build flag affects timeout behavior as indicated in the description of the net_retry_count system variable.

  • new

    Command-Line Format--new
    System VariableNamenew
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Disabled byskip-new
    Permitted ValuesTypeboolean
    DefaultFALSE

    This variable was used in MySQL 4.0 to turn on some 4.1 behaviors, and is retained for backward compatibility. Its value is always OFF.

  • old_passwords

    System VariableNameold_passwords
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default0

    This variable controls the password hashing method used by the PASSWORD() function. It also influences password hashing performed by CREATE USER and GRANT statements that specify a password using an IDENTIFIED BY clause.

    The value determines whether or not to use old native MySQL password hashing. A value of 0 (or OFF) causes passwords to be encrypted using the format available from MySQL 4.1 on. A value of 1 (or ON) causes password encryption to use the older pre-4.1 format.

    If old_passwords=1, PASSWORD(str) returns the same value as OLD_PASSWORD(str). The latter function is not affected by the value of old_passwords.

    For information about hashing formats, see Section 6.1.2.4, “Password Hashing in MySQL”.

  • one_shot

    This is not a variable, but it can be used when setting some variables. It is described in Section 13.7.4, “SET Syntax”.

  • open_files_limit

    Command-Line Format--open-files-limit=#
    System VariableNameopen_files_limit
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Valueplatform dependent

    The number of files that the operating system permits mysqld to open. This is the real value permitted by the system and might be different from the value you gave using the --open-files-limit option to mysqld or mysqld_safe. The value is 0 on systems where MySQL cannot change the number of open files.

  • optimizer_prune_level

    Introduced5.0.1
    Command-Line Format--optimizer_prune_level[=#]
    System VariableNameoptimizer_prune_level
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default1

    Controls the heuristics applied during query optimization to prune less-promising partial plans from the optimizer search space. A value of 0 disables heuristics so that the optimizer performs an exhaustive search. A value of 1 causes the optimizer to prune plans based on the number of rows retrieved by intermediate plans. This variable was added in MySQL 5.0.1.

  • optimizer_search_depth

    Introduced5.0.1
    Command-Line Format--optimizer_search_depth[=#]
    System VariableNameoptimizer_search_depth
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default62
    Min Value0
    Max Value63

    The maximum depth of search performed by the query optimizer. Values larger than the number of relations in a query result in better query plans, but take longer to generate an execution plan for a query. Values smaller than the number of relations in a query return an execution plan quicker, but the resulting plan may be far from being optimal. If set to 0, the system automatically picks a reasonable value. If set to 63, the optimizer switches to the algorithm used in MySQL 5.0.0 (and previous versions) for performing searches. This variable was added in MySQL 5.0.1.

  • pid_file

    Command-Line Format--pid-file=file_name
    System VariableNamepid_file
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The path name of the process ID (PID) file. This variable can be set with the --pid-file option.

  • plugin_dir

    Introduced5.0.67
    Command-Line Format--plugin_dir=dir_name
    System VariableNameplugin_dir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name
    Default

    The path name of the plugin directory. This variable was added in MySQL 5.0.67. If the value is nonempty, user-defined function object files must be located in this directory. If the value is empty, the behavior that is used before 5.0.67 applies: The UDF object files must be located in a directory that is searched by your system's dynamic linker.

    If the plugin directory is writable by the server, it may be possible for a user to write executable code to a file in the directory using SELECT ... INTO DUMPFILE. This can be prevented by making plugin_dir read only to the server or by setting --secure-file-priv to a directory where SELECT writes can be made safely.

  • port

    Command-Line Format--port=#
    System VariableNameport
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default3306
    Min Value0
    Max Value65535

    The number of the port on which the server listens for TCP/IP connections. This variable can be set with the --port option.

  • preload_buffer_size

    Command-Line Format--preload_buffer_size=#
    System VariableNamepreload_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default32768
    Min Value1024
    Max Value1073741824

    The size of the buffer that is allocated when preloading indexes.

  • prepared_stmt_count

    Introduced5.0.21
    Removed5.0.31
    System Variable (>= 5.0.21, <= 5.0.31)Nameprepared_stmt_count
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger

    The current number of prepared statements. (The maximum number of statements is given by the max_prepared_stmt_count system variable.) This variable was added in MySQL 5.0.21. In MySQL 5.0.32, it was converted to the global Prepared_stmt_count status variable.

  • profiling

    If set to 0 or OFF (the default), statement profiling is disabled. If set to 1 or ON, statement profiling is enabled and the SHOW PROFILE and SHOW PROFILES statements provide access to profiling information. See Section 13.7.5.29, “SHOW PROFILES Syntax”. This variable was added in MySQL 5.0.37. Note: This option does not apply to MySQL Enterprise Server users.

  • profiling_history_size

    The number of statements for which to maintain profiling information if profiling is enabled. The default value is 15. The maximum value is 100. Setting the value to 0 effectively disables profiling. See Section 13.7.5.29, “SHOW PROFILES Syntax”. This variable was added in MySQL 5.0.37. Note: This option does not apply to MySQL Enterprise Server users.

  • protocol_version

    System VariableNameprotocol_version
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger

    The version of the client/server protocol used by the MySQL server.

  • pseudo_thread_id

    System VariableNamepseudo_thread_id
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeinteger

    This variable is for internal server use.

  • query_alloc_block_size

    Command-Line Format--query_alloc_block_size=#
    System VariableNamequery_alloc_block_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default8192
    Min Value1024
    Max Value4294967295
    Block Size1024
    Permitted Values (64-bit platforms)Typeinteger
    Default8192
    Min Value1024
    Max Value18446744073709547520
    Block Size1024

    The allocation size of memory blocks that are allocated for objects created during statement parsing and execution. If you have problems with memory fragmentation, it might help to increase this parameter.

  • query_cache_limit

    Command-Line Format--query_cache_limit=#
    System VariableNamequery_cache_limit
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default1048576
    Min Value0
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default1048576
    Min Value0
    Max Value18446744073709547520

    Do not cache results that are larger than this number of bytes. The default value is 1MB.

  • query_cache_min_res_unit

    Command-Line Format--query_cache_min_res_unit=#
    System VariableNamequery_cache_min_res_unit
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default4096
    Min Value512
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default4096
    Min Value512
    Max Value18446744073709547520

    The minimum size (in bytes) for blocks allocated by the query cache. The default value is 4096 (4KB). Tuning information for this variable is given in Section 8.10.3.3, “Query Cache Configuration”.

  • query_cache_size

    Command-Line Format--query_cache_size=#
    System VariableNamequery_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default0
    Min Value0
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default0
    Min Value0
    Max Value18446744073709547520

    The amount of memory allocated for caching query results. The default value is 0, which disables the query cache. The permissible values are multiples of 1024; other values are rounded down to the nearest multiple. query_cache_size bytes of memory are allocated even if query_cache_type is set to 0. See Section 8.10.3.3, “Query Cache Configuration”, for more information.

    The query cache needs a minimum size of about 40KB to allocate its structures. (The exact size depends on system architecture.) If you set the value of query_cache_size too small, a warning will occur, as described in Section 8.10.3.3, “Query Cache Configuration”.

  • query_cache_type

    Command-Line Format--query_cache_type=#
    System VariableNamequery_cache_type
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    Default1
    Valid Values0
    1
    2

    Set the query cache type. Setting the GLOBAL value sets the type for all clients that connect thereafter. Individual clients can set the SESSION value to affect their own use of the query cache. Possible values are shown in the following table.

    OptionDescription
    0 or OFFDo not cache results in or retrieve results from the query cache. Note that this does not deallocate the query cache buffer. To do that, you should set query_cache_size to 0.
    1 or ONCache all cacheable query results except for those that begin with SELECT SQL_NO_CACHE.
    2 or DEMANDCache results only for cacheable queries that begin with SELECT SQL_CACHE.

    This variable defaults to ON.

    Any unique prefix of a valid value may be used to set the value of this variable.

  • query_cache_wlock_invalidate

    Command-Line Format--query_cache_wlock_invalidate
    System VariableNamequery_cache_wlock_invalidate
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultFALSE

    Normally, when one client acquires a WRITE lock on a MyISAM table, other clients are not blocked from issuing statements that read from the table if the query results are present in the query cache. Setting this variable to 1 causes acquisition of a WRITE lock for a table to invalidate any queries in the query cache that refer to the table. This forces other clients that attempt to access the table to wait while the lock is in effect.

  • query_prealloc_size

    Command-Line Format--query_prealloc_size=#
    System VariableNamequery_prealloc_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default8192
    Min Value8192
    Max Value4294967295
    Block Size1024
    Permitted Values (64-bit platforms)Typeinteger
    Default8192
    Min Value8192
    Max Value18446744073709547520
    Block Size1024

    The size of the persistent buffer used for statement parsing and execution. This buffer is not freed between statements. If you are running complex queries, a larger query_prealloc_size value might be helpful in improving performance, because it can reduce the need for the server to perform memory allocation during query execution operations.

  • rand_seed1

    The rand_seed1 and rand_seed2 variables exist as session variables only, and can be set but not read. They are not shown in the output of SHOW VARIABLES.

    The purpose of these variables is to support replication of the RAND() function. For statements that invoke RAND(), the master passes two values to the slave, where they are used to seed the random number generator. The slave uses these values to set the session variables rand_seed1 and rand_seed2 so that RAND() on the slave generates the same value as on the master.

  • rand_seed2

    See the description for rand_seed1.

  • range_alloc_block_size

    Command-Line Format--range_alloc_block_size=#
    System VariableNamerange_alloc_block_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default4096
    Min Value4096
    Max Value4294967295
    Block Size1024

    The size of blocks that are allocated when doing range optimization.

  • read_buffer_size

    Command-Line Format--read_buffer_size=#
    System VariableNameread_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default131072
    Min Value8200
    Max Value2147479552

    Each thread that does a sequential scan allocates a buffer of this size (in bytes) for each table it scans. If you do many sequential scans, you might want to increase this value, which defaults to 131072. The value of this variable should be a multiple of 4KB. If it is set to a value that is not a multiple of 4KB, its value will be rounded down to the nearest multiple of 4KB.

    The maximum permissible setting for read_buffer_size is 2GB.

    read_buffer_size and read_rnd_buffer_size are not specific to any storage engine and apply in a general manner for optimization. See Section 8.12.5.1, “How MySQL Uses Memory”, for example.

  • read_only

    Command-Line Format--read_only
    System VariableNameread_only
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    When the read_only system variable is enabled, the server permits no client updates except from users who have the SUPER privilege. This variable is disabled by default.

    Even with read_only enabled, the server permits these operations:

    • Updates performed by slave threads, if the server is a replication slave. In replication setups, it can be useful to enable read_only on slave servers to ensure that slaves accept updates only from the master server and not from clients.

    • Use of ANALYZE TABLE or OPTIMIZE TABLE statements. The purpose of read-only mode is to prevent changes to table structure or contents. Analysis and optimization do not qualify as such changes. This means, for example, that consistency checks on read-only replication slaves can be performed with mysqlcheck --all-databases --analyze.

    • Operations on TEMPORARY tables, as of MySQL 5.0.16.

    read_only exists only as a GLOBAL variable, so changes to its value require the SUPER privilege. Changes to read_only on a master server are not replicated to slave servers. The value can be set on a slave server independent of the setting on the master.

    Important

    As of MySQL 5.1, enabling read_only prevents users not having the SUPER privilege from using account-management statements such as CREATE USER or SET PASSWORD. This is not the case for MySQL 5.0. When replicating from a MySQL 5.0 master to a MySQL 5.1 or later slave, check whether this will have an impact on your applications.

  • read_rnd_buffer_size

    Command-Line Format--read_rnd_buffer_size=#
    System VariableNameread_rnd_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default262144
    Min Value8200
    Max Value2147483647

    When reading rows in sorted order following a key-sorting operation, the rows are read through this buffer to avoid disk seeks. See Section 8.2.1.11, “ORDER BY Optimization”. Setting the variable to a large value can improve ORDER BY performance by a lot. However, this is a buffer allocated for each client, so you should not set the global variable to a large value. Instead, change the session variable only from within those clients that need to run large queries.

    The maximum permissible setting for read_rnd_buffer_size is 2GB.

    read_buffer_size and read_rnd_buffer_size are not specific to any storage engine and apply in a general manner for optimization. See Section 8.12.5.1, “How MySQL Uses Memory”, for example.

  • relay_log_purge

    Command-Line Format--relay_log_purge
    System VariableNamerelay_log_purge
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultTRUE

    Disables or enables automatic purging of relay log files as soon as they are not needed any more. The default value is 1 (ON).

  • relay_log_space_limit

    Command-Line Format--relay_log_space_limit=#
    System VariableNamerelay_log_space_limit
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default0
    Min Value0
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default0
    Min Value0
    Max Value18446744073709547520

    The maximum amount of space to use for all relay logs.

  • secure_auth

    Command-Line Format--secure-auth
    System VariableNamesecure_auth
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    If this variable is enabled, the server blocks connections by clients that attempt to use accounts that have passwords stored in the old (pre-4.1) format.

    Enable this variable to prevent all use of passwords employing the old format (and hence insecure communication over the network).

    Server startup fails with an error if this variable is enabled and the privilege tables are in pre-4.1 format. See Section B.5.2.4, “Client does not support authentication protocol”.

  • secure_file_priv

    Introduced5.0.38
    Command-Line Format--secure-file-priv=dir_name
    System VariableNamesecure_file_priv
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring
    Defaultempty
    Valid Valuesempty
    dirname

    This variable is used to limit the effect of data import and export operations, such as those performed by the LOAD DATA and SELECT ... INTO OUTFILE statements and the LOAD_FILE() function. By default, this variable is empty. If set to the name of a directory, it limits import and export operations to work only with files in that directory.

    This variable was added in MySQL 5.0.38.

  • server_id

    Command-Line Format--server-id=#
    System VariableNameserver_id
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value4294967295

    The server ID, used in replication to give each master and slave a unique identity. This variable is set by the --server-id option. For each server participating in replication, you should pick a positive integer in the range from 1 to 232 − 1 to act as that server's ID.

  • shared_memory

    Command-Line Format--shared_memory[={0,1}]
    System VariableNameshared_memory
    Variable ScopeGlobal
    Dynamic VariableNo
    Platform SpecificWindows
    Permitted ValuesTypeboolean
    DefaultFALSE

    (Windows only.) Whether the server permits shared-memory connections.

  • shared_memory_base_name

    Command-Line Format--shared_memory_base_name=name
    System VariableNameshared_memory_base_name
    Variable ScopeGlobal
    Dynamic VariableNo
    Platform SpecificWindows
    Permitted ValuesTypestring
    DefaultMYSQL

    (Windows only.) The name of shared memory to use for shared-memory connections. This is useful when running multiple MySQL instances on a single physical machine. The default name is MYSQL. The name is case sensitive.

  • skip_external_locking

    Command-Line Format--skip-external-locking
    System VariableNameskip_external_locking
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeboolean
    DefaultON

    This is OFF if mysqld uses external locking (system locking), ON if external locking is disabled. This affects only MyISAM table access.

    This variable is set by the --external-locking or --skip-external-locking option. External locking is disabled by default.

    External locking affects only MyISAM table access. For more information, including conditions under which it can and cannot be used, see Section 8.11.4, “External Locking”.

  • skip_networking

    Command-Line Format--skip-networking
    System VariableNameskip_networking
    Variable ScopeGlobal
    Dynamic VariableNo

    This is ON if the server permits only local (non-TCP/IP) connections. On Unix, local connections use a Unix socket file. On Windows, local connections use a named pipe or shared memory. On NetWare, only TCP/IP connections are supported, so do not set this variable to ON. This variable can be set to ON with the --skip-networking option.

  • skip_show_database

    Command-Line Format--skip-show-database
    System VariableNameskip_show_database
    Variable ScopeGlobal
    Dynamic VariableNo

    This prevents people from using the SHOW DATABASES statement if they do not have the SHOW DATABASES privilege. This can improve security if you have concerns about users being able to see databases belonging to other users. Its effect depends on the SHOW DATABASES privilege: If the variable value is ON, the SHOW DATABASES statement is permitted only to users who have the SHOW DATABASES privilege, and the statement displays all database names. If the value is OFF, SHOW DATABASES is permitted to all users, but displays the names of only those databases for which the user has the SHOW DATABASES or other privilege. (Note that any global privilege is considered a privilege for the database.)

  • slow_launch_time

    Command-Line Format--slow_launch_time=#
    System VariableNameslow_launch_time
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default2

    If creating a thread takes longer than this many seconds, the server increments the Slow_launch_threads status variable.

  • socket

    Command-Line Format--socket={file_name|pipe_name}
    System VariableNamesocket
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring
    Default/tmp/mysql.sock

    On Unix platforms, this variable is the name of the socket file that is used for local client connections. The default is /tmp/mysql.sock. (For some distribution formats, the directory might be different, such as /var/lib/mysql for RPMs.)

    On Windows, this variable is the name of the named pipe that is used for local client connections. The default value is MySQL (not case sensitive).

  • sort_buffer_size

    Command-Line Format--sort_buffer_size=#
    System VariableNamesort_buffer_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default2097144
    Min Value32768
    Max Value4294967295

    Each session that needs to do a sort allocates a buffer of this size. sort_buffer_size is not specific to any storage engine and applies in a general manner for optimization. See Section 8.2.1.11, “ORDER BY Optimization”, for example.

    If you see many Sort_merge_passes per second in SHOW GLOBAL STATUS output, you can consider increasing the sort_buffer_size value to speed up ORDER BY or GROUP BY operations that cannot be improved with query optimization or improved indexing. The entire buffer is allocated even if it is not all needed, so setting it larger than required globally will slow down most queries that sort. It is best to increase it as a session setting, and only for the sessions that need a larger size. On Linux, there are thresholds of 256KB and 2MB where larger values may significantly slow down memory allocation, so you should consider staying below one of those values. Experiment to find the best value for your workload. See Section B.5.3.5, “Where MySQL Stores Temporary Files”.

    The maximum permissible setting for sort_buffer_size is 4GB−1.

  • sql_auto_is_null

    System VariableNamesql_auto_is_null
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default1

    If this variable is set to 1 (the default), then after a statement that successfully inserts an automatically generated AUTO_INCREMENT value, you can find that value by issuing a statement of the following form:

    SELECT * FROM tbl_name WHERE auto_col IS NULL
    

    If the statement returns a row, the value returned is the same as if you invoked the LAST_INSERT_ID() function. For details, including the return value after a multiple-row insert, see Section 12.13, “Information Functions”. If no AUTO_INCREMENT value was successfully inserted, the SELECT statement returns no row.

    The behavior of retrieving an AUTO_INCREMENT value by using an IS NULL comparison is used by some ODBC programs, such as Access. See Obtaining Auto-Increment Values. This behavior can be disabled by setting sql_auto_is_null to 0.

  • sql_big_selects

    System VariableNamesql_big_selects
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default1

    If set to 0, MySQL aborts SELECT statements that are likely to take a very long time to execute (that is, statements for which the optimizer estimates that the number of examined rows exceeds the value of max_join_size). This is useful when an inadvisable WHERE statement has been issued. The default value for a new connection is 1, which permits all SELECT statements.

    If you set the max_join_size system variable to a value other than DEFAULT, sql_big_selects is set to 0.

  • sql_buffer_result

    System VariableNamesql_buffer_result
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default0

    If set to 1, sql_buffer_result forces results from SELECT statements to be put into temporary tables. This helps MySQL free the table locks early and can be beneficial in cases where it takes a long time to send results to the client. The default value is 0.

  • sql_log_bin

    System VariableNamesql_log_bin
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean

    If set to 0, no logging is done to the binary log for the client. The client must have the SUPER privilege to set this option. The default value is 1.

  • sql_log_off

    System VariableNamesql_log_off
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default0

    If set to 1, no logging is done to the general query log for this client. The client must have the SUPER privilege to set this option. The default value is 0.

  • sql_log_update

    Deprecated5.0.0, by sql_log_bin
    System VariableNamesql_log_update
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean

    This variable is deprecated, and is mapped to sql_log_bin. It is removed in MySQL 5.5.

  • sql_mode

    Command-Line Format--sql-mode=name
    System VariableNamesql_mode
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeset
    Default''
    Valid ValuesALLOW_INVALID_DATES
    ANSI_QUOTES
    ERROR_FOR_DIVISION_BY_ZERO
    HIGH_NOT_PRECEDENCE
    IGNORE_SPACE
    NO_AUTO_CREATE_USER
    NO_AUTO_VALUE_ON_ZERO
    NO_BACKSLASH_ESCAPES
    NO_DIR_IN_CREATE
    NO_ENGINE_SUBSTITUTION
    NO_FIELD_OPTIONS
    NO_KEY_OPTIONS
    NO_TABLE_OPTIONS
    NO_UNSIGNED_SUBTRACTION
    NO_ZERO_DATE
    NO_ZERO_IN_DATE
    ONLY_FULL_GROUP_BY
    PAD_CHAR_TO_FULL_LENGTH
    PIPES_AS_CONCAT
    REAL_AS_FLOAT
    STRICT_ALL_TABLES
    STRICT_TRANS_TABLES

    The current server SQL mode, which can be set dynamically. For details, see Section 5.1.7, “Server SQL Modes”.

    Note

    MySQL installation programs may configure the SQL mode during the installation process. If the SQL mode differs from the default or from what you expect, check for a setting in an option file that the server reads at startup.

  • sql_notes

    If set to 1 (the default), warnings of Note level increment warning_count and the server records them. If set to 0, Note warnings do not increment warning_count and the server does not record them. mysqldump includes output to set this variable to 0 so that reloading the dump file does not produce warnings for events that do not affect the integrity of the reload operation. sql_notes was added in MySQL 5.0.3.

  • sql_quote_show_create

    If set to 1 (the default), the server quotes identifiers for SHOW CREATE TABLE and SHOW CREATE DATABASE statements. If set to 0, quoting is disabled. This option is enabled by default so that replication works for identifiers that require quoting. See Section 13.7.5.9, “SHOW CREATE TABLE Syntax”, and Section 13.7.5.6, “SHOW CREATE DATABASE Syntax”.

  • sql_safe_updates

    If set to 1, MySQL aborts UPDATE or DELETE statements that do not use a key in the WHERE clause or a LIMIT clause. (Specifically, UPDATE statements must have a WHERE clause that uses a key or a LIMIT clause, or both. DELETE statements must have both.) This makes it possible to catch UPDATE or DELETE statements where keys are not used properly and that would probably change or delete a large number of rows. The default value is 0.

  • sql_select_limit

    System VariableNamesql_select_limit
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeinteger

    The maximum number of rows to return from SELECT statements. The default value for a new connection is the maximum number of rows that the server permits per table, which depends on the server configuration and may be affected if the server build was configured with --with-big-tables. Typical default values are (232)−1 or (264)−1. If you have changed the limit, the default value can be restored by assigning a value of DEFAULT.

    If a SELECT has a LIMIT clause, the LIMIT takes precedence over the value of sql_select_limit.

  • sql_warnings

    This variable controls whether single-row INSERT statements produce an information string if warnings occur. The default is 0. Set the value to 1 to produce an information string.

  • ssl_ca

    Introduced5.0.23
    Command-Line Format--ssl-ca=file_name
    System VariableNamessl_ca
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The path to a file with a list of trusted SSL CAs. This variable was added in MySQL 5.0.23.

  • ssl_capath

    Introduced5.0.23
    Command-Line Format--ssl-capath=dir_name
    System VariableNamessl_capath
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The path to a directory that contains trusted SSL CA certificates in PEM format. This variable was added in MySQL 5.0.23.

  • ssl_cert

    Introduced5.0.23
    Command-Line Format--ssl-cert=file_name
    System VariableNamessl_cert
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The name of the SSL certificate file to use for establishing a secure connection. This variable was added in MySQL 5.0.23.

  • ssl_cipher

    Introduced5.0.23
    Command-Line Format--ssl-cipher=name
    System VariableNamessl_cipher
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring

    A list of permissible ciphers to use for SSL encryption. This variable was added in MySQL 5.0.23.

  • ssl_key

    Introduced5.0.23
    Command-Line Format--ssl-key=file_name
    System VariableNamessl_key
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The name of the SSL key file to use for establishing a secure connection. This variable was added in MySQL 5.0.23.

  • storage_engine

    System VariableNamestorage_engine
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    DefaultMyISAM

    The default storage engine (table type). To set the storage engine at server startup, use the --default-storage-engine option. See Section 5.1.3, “Server Command Options”.

    To see which storage engines are available and enabled, use the SHOW ENGINES statement.

  • sync_frm

    Command-Line Format--sync-frm
    System VariableNamesync_frm
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultTRUE

    If this variable is set to 1, when any nontemporary table is created its .frm file is synchronized to disk (using fdatasync()). This is slower but safer in case of a crash. The default is 1.

  • system_time_zone

    System VariableNamesystem_time_zone
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring

    The server system time zone. When the server begins executing, it inherits a time zone setting from the machine defaults, possibly modified by the environment of the account used for running the server or the startup script. The value is used to set system_time_zone. Typically the time zone is specified by the TZ environment variable. It also can be specified using the --timezone option of the mysqld_safe script.

    The system_time_zone variable differs from time_zone. Although they might have the same value, the latter variable is used to initialize the time zone for each client that connects. See Section 10.6, “MySQL Server Time Zone Support”.

  • table_cache

    Command-Line Format--table_cache=#
    System VariableNametable_cache
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default64
    Min Value1
    Max Value524288

    The number of open tables for all threads. Increasing this value increases the number of file descriptors that mysqld requires. You can check whether you need to increase the table cache by checking the Opened_tables status variable. See Section 5.1.6, “Server Status Variables”. If the value of Opened_tables is large and you do not use FLUSH TABLES often (which just forces all tables to be closed and reopened), then you should increase the value of the table_cache variable. For more information about the table cache, see Section 8.4.3.1, “How MySQL Opens and Closes Tables”.

  • table_lock_wait_timeout

    Introduced5.0.10
    Command-Line Format--table_lock_wait_timeout=#
    System VariableNametable_lock_wait_timeout
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default50
    Min Value1
    Max Value1073741824

    This variable is unused.

  • table_type

    System VariableNametable_type
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration

    This variable is a synonym for storage_engine, which is the preferred name; table_type is deprecated and is removed in MySQL 5.5.

  • thread_cache_size

    Command-Line Format--thread_cache_size=#
    System VariableNamethread_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value16384

    How many threads the server should cache for reuse. When a client disconnects, the client's threads are put in the cache if there are fewer than thread_cache_size threads there. Requests for threads are satisfied by reusing threads taken from the cache if possible, and only when the cache is empty is a new thread created. This variable can be increased to improve performance if you have a lot of new connections. Normally, this does not provide a notable performance improvement if you have a good thread implementation. However, if your server sees hundreds of connections per second you should normally set thread_cache_size high enough so that most new connections use cached threads. By examining the difference between the Connections and Threads_created status variables, you can see how efficient the thread cache is. For details, see Section 5.1.6, “Server Status Variables”.

  • thread_concurrency

    Command-Line Format--thread_concurrency=#
    System VariableNamethread_concurrency
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeinteger
    Default10
    Min Value1
    Max Value512

    This variable is specific to Solaris systems, for which mysqld invokes the thr_setconcurrency() with the variable value. This function enables applications to give the threads system a hint about the desired number of threads that should be run at the same time.

  • thread_stack

    Command-Line Format--thread_stack=#
    System VariableNamethread_stack
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted Values (32-bit platforms)Typeinteger
    Default196608
    Min Value131072
    Max Value4294967295
    Block Size1024
    Permitted Values (64-bit platforms)Typeinteger
    Default262144
    Min Value131072
    Max Value18446744073709547520
    Block Size1024

    The stack size for each thread. Many of the limits detected by the crash-me test are dependent on this value. See Section 8.13.2, “The MySQL Benchmark Suite”. The default of 192KB (256KB for 64-bit systems) is large enough for normal operation. If the thread stack size is too small, it limits the complexity of the SQL statements that the server can handle, the recursion depth of stored procedures, and other memory-consuming actions.

  • time_format

    This variable is unused.

  • time_zone

    System VariableNametime_zone
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypestring

    The current time zone. This variable is used to initialize the time zone for each client that connects. By default, the initial value of this is 'SYSTEM' (which means, use the value of system_time_zone). The value can be specified explicitly at server startup with the --default-time-zone option. See Section 10.6, “MySQL Server Time Zone Support”.

  • timed_mutexes

    Introduced5.0.3
    Command-Line Format--timed_mutexes
    System VariableNametimed_mutexes
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    This variable controls whether InnoDB mutexes are timed. If this variable is set to 0 or OFF (the default), mutex timing is disabled. If the variable is set to 1 or ON, mutex timing is enabled. With timing enabled, the os_wait_times value in the output from SHOW ENGINE INNODB MUTEX indicates the amount of time (in ms) spent in operating system waits. Otherwise, the value is 0. This variable was added in MySQL 5.0.3.

  • timestamp

    System VariableNametimestamp
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypenumeric

    Set the time for this client. This is used to get the original timestamp if you use the binary log to restore rows. timestamp_value should be a Unix epoch timestamp (a value like that returned by UNIX_TIMESTAMP(), not a value in 'YYYY-MM-DD hh:mm:ss' format) or DEFAULT.

    Setting timestamp to a constant value causes it to retain that value until it is changed again. Setting timestamp to DEFAULT causes its value to be the current date and time as of the time it is accessed.

    SET timestamp affects the value returned by NOW() but not by SYSDATE(). This means that timestamp settings in the binary log have no effect on invocations of SYSDATE(). The server can be started with the --sysdate-is-now option to cause SYSDATE() to be an alias for NOW(), in which case SET timestamp affects both functions.

  • tmp_table_size

    Command-Line Format--tmp_table_size=#
    System VariableNametmp_table_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (<= 5.0.85)Typeinteger
    Default33554432
    Min Value1024
    Max Value4294967295
    Permitted Values (>= 5.0.86)Typeinteger
    Default33554432
    Min Value1024
    Max Value9223372036854775807

    The maximum size of internal in-memory temporary tables. This variable does not apply to user-created MEMORY tables.

    The actual limit is determined as the minimum of tmp_table_size and max_heap_table_size. If an in-memory temporary table exceeds the limit, MySQL automatically converts it to an on-disk MyISAM table. Increase the value of tmp_table_size (and max_heap_table_size if necessary) if you do many advanced GROUP BY queries and you have lots of memory.

    You can compare the number of internal on-disk temporary tables created to the total number of internal temporary tables created by comparing the values of the Created_tmp_disk_tables and Created_tmp_tables variables.

    See also Section 8.4.4, “Internal Temporary Table Use in MySQL”.

  • tmpdir

    Command-Line Format--tmpdir=dir_name
    System VariableNametmpdir
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypedirectory name

    The directory used for temporary files and temporary tables. This variable can be set to a list of several paths that are used in round-robin fashion. Paths should be separated by colon characters (:) on Unix and semicolon characters (;) on Windows, NetWare, and OS/2.

    The multiple-directory feature can be used to spread the load between several physical disks. If the MySQL server is acting as a replication slave, you should not set tmpdir to point to a directory on a memory-based file system or to a directory that is cleared when the server host restarts. A replication slave needs some of its temporary files to survive a machine restart so that it can replicate temporary tables or LOAD DATA INFILE operations. If files in the temporary file directory are lost when the server restarts, replication fails. You can set the slave's temporary directory using the slave_load_tmpdir variable. In that case, the slave will not use the general tmpdir value and you can set tmpdir to a nonpermanent location.

  • transaction_alloc_block_size

    Command-Line Format--transaction_alloc_block_size=#
    System VariableNametransaction_alloc_block_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default8192
    Min Value1024
    Max Value4294967295
    Block Size1024
    Permitted Values (64-bit platforms)Typeinteger
    Default8192
    Min Value1024
    Max Value18446744073709547520
    Block Size1024

    The amount in bytes by which to increase a per-transaction memory pool which needs memory. See the description of transaction_prealloc_size.

  • transaction_prealloc_size

    Command-Line Format--transaction_prealloc_size=#
    System VariableNametransaction_prealloc_size
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default4096
    Min Value1024
    Max Value4294967295
    Block Size1024
    Permitted Values (64-bit platforms)Typeinteger
    Default4096
    Min Value1024
    Max Value18446744073709547520
    Block Size1024

    There is a per-transaction memory pool from which various transaction-related allocations take memory. The initial size of the pool in bytes is transaction_prealloc_size. For every allocation that cannot be satisfied from the pool because it has insufficient memory available, the pool is increased by transaction_alloc_block_size bytes. When the transaction ends, the pool is truncated to transaction_prealloc_size bytes.

    By making transaction_prealloc_size sufficiently large to contain all statements within a single transaction, you can avoid many malloc() calls.

  • tx_isolation

    System VariableNametx_isolation
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    DefaultREPEATABLE-READ
    Valid ValuesREAD-UNCOMMITTED
    READ-COMMITTED
    REPEATABLE-READ
    SERIALIZABLE

    The default transaction isolation level. Defaults to REPEATABLE-READ.

    This variable can be set directly, or indirectly using the SET TRANSACTION statement. See Section 13.3.6, “SET TRANSACTION Syntax”. If you set tx_isolation directly to an isolation level name that contains a space, the name should be enclosed within quotation marks, with the space replaced by a dash. For example:

    SET tx_isolation = 'READ-COMMITTED';
    

    Any unique prefix of a valid value may be used to set the value of this variable.

    The default transaction isolation level can also be set at startup using the --transaction-isolation server option.

  • unique_checks

    System VariableNameunique_checks
    Variable ScopeSession
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default1

    If set to 1 (the default), uniqueness checks for secondary indexes in InnoDB tables are performed. If set to 0, storage engines are permitted to assume that duplicate keys are not present in input data. If you know for certain that your data does not contain uniqueness violations, you can set this to 0 to speed up large table imports to InnoDB.

    Setting this variable to 0 does not require storage engines to ignore duplicate keys. An engine is still permitted to check for them and issue duplicate-key errors if it detects them.

  • updatable_views_with_limit

    Introduced5.0.2
    Command-Line Format--updatable_views_with_limit=#
    System VariableNameupdatable_views_with_limit
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    Default1

    This variable controls whether updates to a view can be made when the view does not contain all columns of the primary key defined in the underlying table, if the update statement contains a LIMIT clause. (Such updates often are generated by GUI tools.) An update is an UPDATE or DELETE statement. Primary key here means a PRIMARY KEY, or a UNIQUE index in which no column can contain NULL.

    The variable can have two values:

    • 1 or YES: Issue a warning only (not an error message). This is the default value.

    • 0 or NO: Prohibit the update.

    This variable was added in MySQL 5.0.2.

  • version

    System VariableNameversion
    Variable ScopeGlobal
    Dynamic VariableNo

    The version number for the server. The value might also include a suffix indicating server build or configuration information. -log indicates that one or more of the general log, slow query log, or binary log are enabled. -debug indicates that the server was built with debugging support enabled.

    System VariableNameversion
    Variable ScopeGlobal
    Dynamic VariableNo

    Starting with MySQL 5.0.24, the version number will also indicate whether the server is a standard release (Community) or Enterprise release (for example, 5.0.28-enterprise-gpl-nt).

  • version_bdb

    The BDB storage engine version.

  • version_comment

    System VariableNameversion_comment
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring

    The configure script has a --with-comment option that permits a comment to be specified when building MySQL. This variable contains the value of that comment.

    For precompiled binaries, this variable will hold the server version and license information. Starting with MySQL 5.0.24, version_comment will include the full server type and license. For community users this will appear as MySQL Community Edition - Standard (GPL). For Enterprise users, the version might be displayed as MySQL Enterprise Server (GPL). The corresponding license for your MySQL binary is shown in parentheses. For server compiled from source, the default value will be the same as that for Community releases.

  • version_compile_machine

    System VariableNameversion_compile_machine
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring

    The type of machine or architecture on which MySQL was built.

  • version_compile_os

    System VariableNameversion_compile_os
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypestring

    The type of operating system on which MySQL was built.

  • wait_timeout

    Command-Line Format--wait_timeout=#
    System VariableNamewait_timeout
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted Values (Windows)Typeinteger
    Default28800
    Min Value1
    Max Value2147483
    Permitted Values (Other)Typeinteger
    Default28800
    Min Value1
    Max Value31536000

    The number of seconds the server waits for activity on a noninteractive connection before closing it. This timeout applies only to TCP/IP and Unix socket file connections, not to connections made using named pipes, or shared memory.

    On thread startup, the session wait_timeout value is initialized from the global wait_timeout value or from the global interactive_timeout value, depending on the type of client (as defined by the CLIENT_INTERACTIVE connect option to mysql_real_connect()). See also interactive_timeout.

  • warning_count

    The number of errors, warnings, and notes that resulted from the last statement that generated messages. This variable is read only. See Section 13.7.5.37, “SHOW WARNINGS Syntax”.


User Comments
  Posted by NOT_FOUND NOT_FOUND on March 29, 2004
if you set
[mysqld]
ft_min_word_len=3

you should also set
[myisamchk]
ft_min_word_len=3

if you use myisamchk
  Posted by Richard Fearn on March 12, 2007
The description for lower_case_table_names is a bit unclear with regards to the value 0 (but does explain 1 and 2).

A value of 0 means that table & database names are stored as-is, and name comparisons are case sensitive.

There's more information about lower_case_table_names on this page:

http://dev.mysql.com/doc/refman/5.0/en/identifier-case-sensitivity.html

  Posted by David Tonhofer on November 14, 2007
Documentation says "The maximum allowable setting for sort_buffer_size is 4GB." and there is reference to a chapter explaining temporary on-disk files.

However, the fact that on 32-bit GNU/Linux x86, "sort_buffer_size" must be a few MiB only to avoid exceeding maximum process space, as explained in http://dev.mysql.com/doc/refman/5.0/en/innodb-configuration.html makes one infer that that sort_buffer_size is actually some kind of in-memory buffer.

Additionally, the formula should probably be extended:

total =
innodb_buffer_pool_size +
key_buffer_size +
innodb_additional_mem_pool_size +
innodb_log_buffer_size +
max_connections *
(sort_buffer_size +
read_buffer_size +
binlog_cache_size +
maximum_thread_stack_size);

Noting that "key_buffer_size" is a MyISAM parameter

  Posted by DBA Lead on November 29, 2010
there is abug in MySQL server that treat open_files_limit and open-files-limit differently also the limit for open-files-limit mentioned on this page is not entirely true

http://www.geeksww.com/tutorials/database_management_systems/mysql/configuration/mysql_open_files_limit_openfileslimit_vs_openfileslimit_on_linux.php
  Posted by Douglas Manley on May 4, 2011
It appears that the "read_buffer_size" setting is used by the MEMORY table engine as the allocation increment size (minus a few bytes). This means that a MEMORY table with *one row* will take up, essentially, "read_buffer_size" bytes. For each on the table, add on another "read_buffer_size" bytes to the table. The table will not change in size again until all of that allocation is used by new rows; then it will grow in increments again.

This is not documented anywhere as far as I can tell, and I only found it after banging my head against a wall looking through the MySQL source code.
  Posted by John Paterson on September 5, 2013
Many users upgrading from 5.1 to 5.6 will be caught out by this: query_cache_type by default is turned off, even if query_cache_size is set. Previous versions turned on the query cache simply by setting a value for query_cache_size.

We've just upgraded some servers for our CRM systems and itv took us a while to work out why performance was slow!

John Paterson
http://www.reallysimplesystems.com/
Making CRM Simple

  Posted by Rolf Martin-Hoster on October 16, 2014
It should also be noted that the table_definition_cache is also used to cache text/blob data during certain actions. This means it is impractical to think that the memory usage of the table definition cache is a fixed amount in anyway. There are purge functions and limits in place but on a busy system with many tables with large blobs you could see a significant amount of bloat.
Sign Up Login You must be logged in to post a comment.