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 VARIABLESstatement.
This section provides a description of each system variable. Variables with no version indicated are present in all MySQL 5.1 releases.
The following table lists all available system variables.
Table 5.2 System Variable Summary
For additional system variable information, see these sections:
Section 5.1.5, “Using System Variables”, discusses the syntax for setting and displaying system variable values.
Section 5.1.5.2, “Dynamic System Variables”, lists the variables that can be set at runtime.
Information on tuning system variables can be found in Section 8.12.2, “Tuning Server Parameters”.
Section 14.6.7, “InnoDB Startup Options and System Variables”, lists
InnoDBsystem variables.Section 17.3.3.8.2, “MySQL Cluster System Variables”, lists system variables which are specific to MySQL Cluster.
For information on server system variables specific to replication, see Section 16.1.3, “Replication and Binary Logging Options and Variables”.
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.
-
System Variable Name autocommitVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanDefault ONThe autocommit mode. If set to 1, all changes to a table take effect immediately. If set to 0, you must use
COMMITto accept a transaction orROLLBACKto cancel it. Ifautocommitis 0 and you change it to 1, MySQL performs an automaticCOMMITof any open transaction. Another way to begin a transaction is to use aSTART TRANSACTIONorBEGINstatement. See Section 13.3.1, “START TRANSACTION, COMMIT, and ROLLBACK Syntax”.By default, client connections begin with
autocommitset to 1. To cause clients to begin with a default of 0, set the server'sinit_connectsystem variable:SET GLOBAL init_connect='SET autocommit=0';
The
init_connectvariable 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_connectis not executed for users that have theSUPERprivilege. -
System Variable Name automatic_sp_privilegesVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault TRUEWhen this variable has a value of 1 (the default), the server automatically grants the
EXECUTEandALTER ROUTINEprivileges to the creator of a stored routine, if the user cannot already execute and alter or drop the routine. (TheALTER ROUTINEprivilege is required to drop the routine.) The server also automatically drops those privileges from the creator when the routine is dropped. Ifautomatic_sp_privilegesis 0, the server does not automatically add or drop these privileges.The creator of a routine is the account used to execute the
CREATEstatement for it. This might not be the same as the account named as theDEFINERin the routine definition.See also Section 19.2.2, “Stored Routines and MySQL Privileges”.
-
System Variable Name back_logVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 50Min Value 1Max Value 65535The 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_logvalue 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_logcannot be set higher than your operating system limit. -
Command-Line Format --basedir=dir_nameSystem Variable Name basedirVariable Scope Global Dynamic Variable No Permitted Values Type directory nameThe MySQL installation base directory. This variable can be set with the
--basediroption. Relative path names for other variables usually are resolved relative to the base directory. If set to 1, all temporary tables are stored on disk rather than in memory. This is a little slower, but the error
The tabledoes not occur fortbl_nameis fullSELECToperations 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.NoteThis variable was formerly named
sql_big_tables.-
Command-Line Format --bulk_insert_buffer_size=#System Variable Name bulk_insert_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 8388608Min Value 0Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 8388608Min Value 0Max Value 18446744073709547520MyISAMuses a special tree-like cache to make bulk inserts faster forINSERT ... SELECT,INSERT ... VALUES (...), (...), ..., andLOAD DATA INFILEwhen 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. -
System Variable Name character_set_clientVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThe 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-setoption 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
sjiswhen connecting to a server not configured withsjissupport.mysqld was started with the
--skip-character-set-client-handshakeoption, 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.
ucs2cannot be used as a client character set, which means that it also does not work forSET NAMESorSET CHARACTER SET. -
System Variable Name character_set_connectionVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThe character set for the current connection. Used for literals that do not have an explicit character set specification and for number-to-string conversion.
-
System Variable Name character_set_databaseVariable Scope Global, Session Dynamic Variable Yes Footnote This option is dynamic, but only the server should set this information. You should not set the value of this variable manually. Permitted Values Type stringThe 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. -
Introduced 5.1.6 Command-Line Format --character-set-filesystem=nameSystem Variable Name character_set_filesystemVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringDefault binaryThe file system character set. This variable is used to interpret string literals that refer to file names, such as in the
LOAD DATA INFILEandSELECT ... INTO OUTFILEstatements and theLOAD_FILE()function. Such file names are converted fromcharacter_set_clienttocharacter_set_filesystembefore the file opening attempt occurs. The default value isbinary, 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, setcharacter_set_filesystemto'utf8'. This variable was added in MySQL 5.1.6. -
System Variable Name character_set_resultsVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThe character set used for returning query results such as result sets or error messages to the client.
-
Command-Line Format --character-set-serverSystem Variable Name character_set_serverVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringDefault latin1The server's default character set.
-
System Variable Name character_set_systemVariable Scope Global Dynamic Variable No Permitted Values Type stringDefault utf8The character set used by the server for storing identifiers. The value is always
utf8. -
Command-Line Format --character-sets-dir=dir_nameSystem Variable Name character_sets_dirVariable Scope Global Dynamic Variable No Permitted Values Type directory nameThe directory where character sets are installed.
-
System Variable Name collation_connectionVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThe collation of the connection character set.
-
System Variable Name collation_databaseVariable Scope Global, Session Dynamic Variable Yes Footnote This option is dynamic, but only the server should set this information. You should not set the value of this variable manually. Permitted Values Type stringThe 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. -
Command-Line Format --collation-serverSystem Variable Name collation_serverVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringDefault latin1_swedish_ciThe server's default collation.
-
Command-Line Format --completion_type=#System Variable Name completion_typeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 0Valid Values 012The transaction completion type. This variable can take the values shown in the following table.
Value Description 0 COMMITandROLLBACKare unaffected. This is the default value.1 COMMITandROLLBACKare equivalent toCOMMIT AND CHAINandROLLBACK AND CHAIN, respectively. (A new transaction starts immediately with the same isolation level as the just-terminated transaction.)2 COMMITandROLLBACKare equivalent toCOMMIT RELEASEandROLLBACK RELEASE, respectively. (The server disconnects after terminating the transaction.)completion_typeaffects transactions that begin withSTART TRANSACTIONorBEGINand end withCOMMITorROLLBACK. 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 forXA COMMIT,XA ROLLBACK, or whenautocommit=1. -
Command-Line Format --concurrent_insert[=#]System Variable Name concurrent_insertVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 1Valid Values 012If 1 (the default), MySQL permits
INSERTandSELECTstatements to run concurrently forMyISAMtables 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.This variable can take three integer values.
Value Description 0 Disables concurrent inserts 1 (Default) Enables concurrent insert for MyISAMtables that do not have holes2 Enables concurrent inserts for all MyISAMtables, 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”.
-
Command-Line Format --connect_timeout=#System Variable Name connect_timeoutVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.1.22) Type integerDefault 5Min Value 2Max Value 31536000Permitted Values (>= 5.1.23) Type integerDefault 10Min Value 2Max Value 31536000The 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.1.23 and 5 seconds before that.Increasing the
connect_timeoutvalue might help if clients frequently encounter errors of the formLost connection to MySQL server at '.XXX', system error:errno -
Command-Line Format --datadir=dir_nameSystem Variable Name datadirVariable Scope Global Dynamic Variable No Permitted Values Type directory nameThe MySQL data directory. This variable can be set with the
--datadiroption. This variable is unused.
This variable is unused.
-
Command-Line Format --debug[=debug_options]System Variable Name debugVariable Scope Global, Session Dynamic Variable Yes Permitted Values (Unix) Type stringDefault d:t:i:o,/tmp/mysqld.tracePermitted Values (Windows) Type stringDefault d:t:i:O,\mysqld.traceThis variable indicates the current debugging settings. It is available only for servers built with debugging support. The initial value comes from the value of instances of the
--debugoption given at server startup. The global and session values may be set at runtime; theSUPERprivilege is required, even for the session value.Assigning a value that begins with
+or-cause the value to added to or subtracted from the current value:mysql>
SET debug = 'T';mysql>SELECT @@debug;+---------+ | @@debug | +---------+ | T | +---------+ mysql>SET debug = '+P';mysql>SELECT @@debug;+---------+ | @@debug | +---------+ | P:T | +---------+ mysql>SET debug = '-P';mysql>SELECT @@debug;+---------+ | @@debug | +---------+ | T | +---------+This variable was added in MySQL 5.1.7.
-
Introduced 5.1.41 System Variable Name debug_syncVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThis variable is the user interface to the Debug Sync facility. Use of Debug Sync requires that MySQL be configured with the
--enable-debug-syncoption (see Section 2.11.4, “MySQL Source-Configuration Options”). If Debug Sync is not compiled in, this system variable is not available.The global variable value is read only and indicates whether the facility is enabled. By default, Debug Sync is disabled and the value of
debug_syncisOFF. If the server is started with--debug-sync-timeout=, whereNNis a timeout value greater than 0, Debug Sync is enabled and the value ofdebug_syncisON - current signalfollowed by the signal name. Also,Nbecomes the default timeout for individual synchronization points.The session value can be read by any user and will have the same value as the global variable. The session value can be set by users that have the
SUPERprivilege to control synchronization points.For a description of the Debug Sync facility and how to use synchronization points, see MySQL Internals: Test Synchronization.
This variable was added in MySQL 5.1.41.
-
Command-Line Format --default_week_format=#System Variable Name default_week_formatVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Max Value 7The default mode value to use for the
WEEK()function. See Section 12.7, “Date and Time Functions”. -
Command-Line Format --delay-key-write[=name]System Variable Name delay_key_writeVariable Scope Global Dynamic Variable Yes Permitted Values Type enumerationDefault ONValid Values ONOFFALLThis option applies only to
MyISAMtables. It can have one of the following values to affect handling of theDELAY_KEY_WRITEtable option that can be used inCREATE TABLEstatements.Option Description OFFDELAY_KEY_WRITEis ignored.ONMySQL honors any DELAY_KEY_WRITEoption specified inCREATE TABLEstatements. This is the default value.ALLAll new opened tables are treated as if they were created with the DELAY_KEY_WRITEoption enabled.If
DELAY_KEY_WRITEis 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 allMyISAMtables by starting the server with the--myisam-recoveroption (for example,--myisam-recover=BACKUP,FORCE). See Section 5.1.3, “Server Command Options”, and Section 14.5.1, “MyISAM Startup Options”.WarningIf you enable external locking with
--external-locking, there is no protection against index corruption for tables that use delayed key writes. -
Command-Line Format --delayed_insert_limit=#System Variable Name delayed_insert_limitVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 100Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 100Min Value 1Max Value 18446744073709547520After inserting
delayed_insert_limitdelayed rows, theINSERT DELAYEDhandler thread checks whether there are anySELECTstatements pending. If so, it permits them to execute before continuing to insert delayed rows. -
Command-Line Format --delayed_insert_timeout=#System Variable Name delayed_insert_timeoutVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 300How many seconds an
INSERT DELAYEDhandler thread should wait forINSERTstatements before terminating. -
Command-Line Format --delayed_queue_size=#System Variable Name delayed_queue_sizeVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 1000Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 1000Min Value 1Max Value 18446744073709547520This is a per-table limit on the number of rows to queue when handling
INSERT DELAYEDstatements. If the queue becomes full, any client that issues anINSERT DELAYEDstatement waits until there is room in the queue again. -
Command-Line Format --div_precision_increment=#System Variable Name div_precision_incrementVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 4Min Value 0Max Value 30This 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 | +----------------+For more information, see Section 22.4.3, “The DBUG Package”.
-
Command-Line Format --engine-condition-pushdownSystem Variable Name engine_condition_pushdownVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault ONThe 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
NDBCLUSTERstorage engine. Enabling this optimization on a MySQL Server acting as a MySQL Cluster SQL node causesWHEREconditions 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_pushdownvariable controls whether engine condition pushdown is enabled. By default, this variable isON(1). Setting it toOFF(0) disables pushdown. The number of errors that resulted from the last statement that generated messages. This variable is read only. See Section 13.7.5.18, “SHOW ERRORS Syntax”.
-
Introduced 5.1.6 Command-Line Format --event-scheduler[=value]System Variable Name event_schedulerVariable Scope Global Dynamic Variable Yes Permitted Values Type enumerationDefault OFFValid Values ONOFFDISABLEDThis variable indicates the status of the Event Scheduler; as of MySQL 5.1.12, possible values are
ON,OFF, andDISABLED, with the default beingOFF. This variable and its effects on the Event Scheduler's operation are discussed in greater detail in the Overview section of the Events chapter.This variable was added in MySQL 5.1.6.
-
Command-Line Format --expire_logs_days=#System Variable Name expire_logs_daysVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Max Value 99The 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.2, “MySQL Server Logs”.
To remove binary log files manually, use the
PURGE BINARY LOGSstatement. See Section 13.4.1.1, “PURGE BINARY LOGS Syntax”. -
Command-Line Format --flushSystem Variable Name flushVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFIf
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 toONif you start mysqld with the--flushoption. -
Command-Line Format --flush_time=#System Variable Name flush_timeVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Permitted Values (Windows) Type integerDefault 1800Min Value 0If this is set to a nonzero value, all tables are closed every
flush_timeseconds to free up resources and synchronize unflushed data to disk. This option is best used only on systems with minimal resources. If set to 1 (the default), foreign key constraints for
InnoDBtables 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, anALTER TABLEoperation returns an error if a foreign key definition is incorrectly formed. For more information, see Section 13.1.17.3, “Using FOREIGN KEY Constraints”.Disabling foreign key checking can be useful for reloading
InnoDBtables in an order different from that required by their parent/child relationships. See Section 14.6.5.6, “InnoDB and FOREIGN KEY Constraints”.Setting
foreign_key_checksto 0 also affects data definition statements:DROP SCHEMAdrops a schema even if it contains tables that have foreign keys that are referred to by tables outside the schema, andDROP TABLEdrops tables that have foreign keys that are referred to by other tables.NoteSetting
foreign_key_checksto 1 does not trigger a scan of the existing table data. Therefore, rows added to the table whileforeign_key_checks = 0will not be verified for consistency.-
Command-Line Format --ft_boolean_syntax=nameSystem Variable Name ft_boolean_syntaxVariable Scope Global Dynamic Variable Yes Permitted Values Type stringDefault + -><()~*:""&|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.
-
Command-Line Format --ft_max_word_len=#System Variable Name ft_max_word_lenVariable Scope Global Dynamic Variable No Permitted Values Type integerMin Value 10The maximum length of the word to be included in a
FULLTEXTindex.NoteFULLTEXTindexes must be rebuilt after changing this variable. UseREPAIR TABLE.tbl_nameQUICK -
Command-Line Format --ft_min_word_len=#System Variable Name ft_min_word_lenVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 4Min Value 1The minimum length of the word to be included in a
FULLTEXTindex.NoteFULLTEXTindexes must be rebuilt after changing this variable. UseREPAIR TABLE.tbl_nameQUICK -
Command-Line Format --ft_query_expansion_limit=#System Variable Name ft_query_expansion_limitVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 20Min Value 0Max Value 1000The number of top matches to use for full-text searches performed using
WITH QUERY EXPANSION. -
Command-Line Format --ft_stopword_file=file_nameSystem Variable Name ft_stopword_fileVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe 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
storage/myisam/ft_static.cfile). Setting this variable to the empty string ('') disables stopword filtering. See also Section 12.9.4, “Full-Text Stopwords”.NoteFULLTEXTindexes must be rebuilt after changing this variable or the contents of the stopword file. UseREPAIR TABLE.tbl_nameQUICK -
Introduced 5.1.12 Command-Line Format --general-logSystem Variable Name general_logVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFWhether the general query log is enabled. The value can be 0 (or
OFF) to disable the log or 1 (orON) to enable the log. The default value depends on whether the--general_logoption is given (--logbefore MySQL 5.1.29). The destination for log output is controlled by thelog_outputsystem variable; if that value isNONE, no log entries are written even if the log is enabled. Thegeneral_logvariable was added in MySQL 5.1.12. -
Introduced 5.1.12 Command-Line Format --general-log-file=file_name(>= 5.1.29)System Variable Name general_log_fileVariable Scope Global Dynamic Variable Yes Permitted Values Type file nameDefault host_name.logThe name of the general query log file. The default value is
, but the initial value can be changed with thehost_name.log--general_log_fileoption (--logbefore MySQL 5.1.29). This variable was added in MySQL 5.1.12. -
Command-Line Format --group_concat_max_len=#System Variable Name group_concat_max_lenVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 1024Min Value 4Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 1024Min Value 4Max Value 18446744073709547520The maximum permitted result length in bytes for the
GROUP_CONCAT()function. The default is 1024. YESif mysqld supportsARCHIVEtables,NOif not. This variable was removed in MySQL 5.1.14.YESif mysqld supportsBLACKHOLEtables,NOif not. This variable was removed in MySQL 5.1.14.YESif thezlibcompression library is available to the server,NOif not. If not, theCOMPRESS()andUNCOMPRESS()functions cannot be used.YESif statement profiling capability is present,NOif not. If present, theprofilingsystem variable controls whether this capability is enabled or disabled. See Section 13.7.5.33, “SHOW PROFILES Syntax”.This variable was added in MySQL 5.1.24. It is renamed to
have_profilingin MySQL 5.5.YESif thecrypt()system call is available to the server,NOif not. If not, theENCRYPT()function cannot be used.YESif mysqld supportsCSVtables,NOif not.This variable is deprecated and is removed in MySQL 5.6. Use
SHOW ENGINESinstead.YESif mysqld supports dynamic loading of plugins,NOif not. This variable was added in MySQL 5.1.10.YESif mysqld supportsEXAMPLEtables,NOif not. This variable was removed in MySQL 5.1.14.YESif mysqld supportsFEDERATEDtables,NOif not. This variable was removed in MySQL 5.1.14.YESif the server supports spatial data types,NOif not.YESif mysqld supportsInnoDBtables.DISABLEDif--skip-innodbis used.This variable is deprecated and is removed in MySQL 5.6. Use
SHOW ENGINESinstead.This variable appears only for reasons of backward compatibility. It is always
NObecauseISAMtables are no longer supported. This variable was removed in MySQL 5.1.7.YESif mysqld supportsMERGEtables.DISABLEDif--skip-mergeis used. This variable was removed in MySQL 5.1.3.YESif mysqld supports SSL connections,NOif not. As of MySQL 5.1.17, this variable is an alias forhave_ssl.YESif mysqld supports partitioning. Added in MySQL 5.1.1 ashave_partition_engineand renamed tohave_partioningin 5.1.6.This variable is deprecated and is removed in MySQL 5.6. Use
SHOW PLUGINSinstead. For more information, see Chapter 18, Partitioning.YESif mysqld supports the query cache,NOif not.-
Introduced 5.1.5 Removed 5.1.15 System Variable Name have_row_based_replicationVariable Scope Global Dynamic Variable No Permitted Values Type booleanYESif the server can perform replication using row-based binary logging. If the value isNO, the server can use only statement-based logging. See Section 16.1.2, “Replication Formats”. This variable was added in MySQL 5.1.5 and removed in 5.1.15. This variable appears only for reasons of backward compatibility. It is always
NObecauseRAIDtables are no longer supported. This variable was removed in MySQL 5.1.7.YESifRTREEindexes are available,NOif not. (These are used for spatial indexes inMyISAMtables.)YESif mysqld supports SSL connections,NOif not.DISABLEDindicates that the server was compiled with SSL support, but was not started with the appropriate--ssl-options. For more information, see Section 6.3.6.3, “Building MySQL with SSL Support”.xxxThis variable was added in MySQL 5.1.17. Before that, use
have_openssl.YESif symbolic link support is enabled,NOif not. This is required on Unix for support of theDATA DIRECTORYandINDEX DIRECTORYtable options, and on Windows for support of data directory symlinks. If the server is started with the--skip-symbolic-linksoption, the value isDISABLED.-
Introduced 5.1.17 System Variable Name hostnameVariable Scope Global Dynamic Variable No Permitted Values Type stringThe server sets this variable to the server host name at startup. This variable was added in MySQL 5.1.17.
This variable is a synonym for the
last_insert_idvariable. It exists for compatibility with other database systems. You can read its value withSELECT @@identity, and set it usingSET identity.-
Command-Line Format --init-connect=nameSystem Variable Name init_connectVariable Scope Global Dynamic Variable Yes Permitted Values Type stringA 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
autocommitsystem variable to specify that autocommit should be disabled by default, butinit_connectcan be used to achieve the same effect:SET GLOBAL init_connect='SET autocommit=0';
The
init_connectvariable 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_connectis not executed for users that have theSUPERprivilege. This is done so that an erroneous value forinit_connectdoes 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 executinginit_connectfor users that have theSUPERprivilege enables them to open a connection and fix theinit_connectvalue.The server discards any result sets produced by statements in the value of of
init_connect. -
Command-Line Format --init-file=file_nameSystem Variable Name init_fileVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe name of the file specified with the
--init-fileoption 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. No statement terminator such as;,\g, or\Gshould be given at the end of each statement.Note that the
--init-fileoption is unavailable if MySQL was configured with the--disable-grant-optionsoption. See Section 2.11.4, “MySQL Source-Configuration Options”. innodb_xxxInnoDBsystem variables are listed in Section 14.6.7, “InnoDB Startup Options and System Variables”. These variables control many aspects of storage, memory use, and I/O patterns forInnoDBtables, and are especially important in MySQL 5.5 and higher, where InnoDB is the default storage engine.The value to be used by the following
INSERTorALTER TABLEstatement when inserting anAUTO_INCREMENTvalue. This is mainly used with the binary log.-
Command-Line Format --interactive_timeout=#System Variable Name interactive_timeoutVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 28800Min Value 1The 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_INTERACTIVEoption tomysql_real_connect(). See alsowait_timeout. -
Command-Line Format --join_buffer_size=#System Variable Name join_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (<= 5.1.22) Type integerDefault 131072Min Value 8200Max Value 4294967295Permitted Values (Windows, 32-bit platforms, >= 5.1.23) Type integerDefault 131072Min Value 8200Max Value 4294967295Permitted Values (Windows, 64-bit platforms, >= 5.1.23) Type integerDefault 131072Min Value 8228Max Value 4294967295Permitted Values (Other, 32-bit platforms, >= 5.1.23) Type integerDefault 131072Min Value 8200Max Value 4294967295Permitted Values (Other, 64-bit platforms, >= 5.1.23) Type integerDefault 131072Min Value 8228Max Value 18446744073709547520The 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_sizeto 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_sizeis 4GB−1. As of MySQL 5.1.23, larger values are permitted for 64-bit platforms (except 64-bit Windows, for which large values are truncated to 4GB−1 with a warning).For additional information about join buffering, see Section 8.2.1.8, “Nested-Loop Join Algorithms”.
-
Introduced 5.1.21 Command-Line Format --keep_files_on_create=#System Variable Name keep_files_on_createVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault OFFIf a
MyISAMtable is created with noDATA DIRECTORYoption, the.MYDfile is created in the database directory. By default, ifMyISAMfinds an existing.MYDfile in this case, it overwrites it. The same applies to.MYIfiles for tables created with noINDEX DIRECTORYoption. To suppress this behavior, set thekeep_files_on_createvariable toON(1), in which caseMyISAMwill not overwrite existing files and returns an error instead. The default value isOFF(0).If a
MyISAMtable is created with aDATA DIRECTORYorINDEX DIRECTORYoption and an existing.MYDor.MYIfile is found, MyISAM always returns an error. It will not overwrite a file in the specified directory.This variable was added in MySQL 5.1.23.
-
Command-Line Format --key_buffer_size=#System Variable Name key_buffer_sizeVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.1.22) Type integerDefault 8388608Min Value 8Max Value 4294967295Permitted Values (32-bit platforms, >= 5.1.23) Type integerDefault 8388608Min Value 8Max Value 4294967295Permitted Values (64-bit platforms, >= 5.1.23) Type integerDefault 8388608Min Value 8Max Value OS_PER_PROCESS_LIMITIndex blocks for
MyISAMtables are buffered and are shared by all threads.key_buffer_sizeis 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_sizeis 4GB−1 on 32-bit platforms. As of MySQL 5.1.23, larger values are permitted for 64-bit platforms, except 64-bit Windows prior to MySQL 5.1.31, for which large values are truncated to 4GB−1 with a warning. As of MySQL 5.1.31, larger values are also permitted for 64-bit Windows. 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
MyISAMstorage 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 toMyISAM.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 STATUSstatement and examining theKey_read_requests,Key_reads,Key_write_requests, andKey_writesstatus variables. (See Section 13.7.5, “SHOW Syntax”.) TheKey_reads/Key_read_requestsratio should normally be less than 0.01. TheKey_writes/Key_write_requestsratio 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 theDELAY_KEY_WRITEtable option.The fraction of the key buffer in use can be determined using
key_buffer_sizein conjunction with theKey_blocks_unusedstatus variable and the buffer block size, which is available from thekey_cache_block_sizesystem 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
MyISAMkey caches. The size limit of 4GB applies to each cache individually, not as a group. See Section 8.10.1, “The MyISAM Key Cache”. -
Command-Line Format --key_cache_age_threshold=#System Variable Name key_cache_age_thresholdVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 300Min Value 100Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 300Min Value 100Max Value 18446744073709547520This 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”.
-
Command-Line Format --key_cache_block_size=#System Variable Name key_cache_block_sizeVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 1024Min Value 512Max Value 16384The size in bytes of blocks in the key cache. The default value is 1024. See Section 8.10.1, “The MyISAM Key Cache”.
-
Command-Line Format --key_cache_division_limit=#System Variable Name key_cache_division_limitVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 100Min Value 1Max Value 100The 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”.
-
Command-Line Format --language=nameSystem Variable Name languageVariable Scope Global Dynamic Variable No Permitted Values Type directory nameDefault /usr/local/mysql/share/mysql/english/The directory where error messages are located. See Section 10.2, “Setting the Error Message Language”.
-
System Variable Name large_files_supportVariable Scope Global Dynamic Variable No Whether mysqld was compiled with options for large file support.
-
Command-Line Format --large-pagesSystem Variable Name large_pagesVariable Scope Global Dynamic Variable No Platform Specific Linux Permitted Values (Linux) Type booleanDefault FALSEWhether large page support is enabled (via the
--large-pagesoption). See Section 8.12.5.2, “Enabling Large Page Support”. -
System Variable Name large_page_sizeVariable Scope Global Dynamic Variable No Permitted Values (Linux) Type integerDefault 0If 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. See Section 8.12.5.2, “Enabling Large Page Support”.
The value to be returned from
LAST_INSERT_ID(). This is stored in the binary log when you useLAST_INSERT_ID()in a statement that updates a table. Setting this variable does not update the value returned by themysql_insert_id()C API function.-
Introduced 5.1.12 System Variable Name lc_time_namesVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThis 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()andMONTHNAME()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.1.12. -
System Variable Name licenseVariable Scope Global Dynamic Variable No Permitted Values Type stringDefault GPLThe type of license the server has.
-
System Variable Name local_infileVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanWhether
LOCALis supported forLOAD DATA INFILEstatements. If this variable is disabled, clients cannot useLOCALinLOAD DATAstatements. See Section 6.1.6, “Security Issues with LOAD DATA LOCAL”. -
System Variable Name locked_in_memoryVariable Scope Global Dynamic Variable No -
Deprecated 5.1.29, by general-log Command-Line Format --log[=file_name]System Variable (<= 5.1.22) Name logVariable Scope Global Dynamic Variable No System Variable (>= 5.1.23) Name logVariable Scope Global Dynamic Variable Yes Permitted Values Type file nameWhether logging of all statements to the general query log is enabled. See Section 5.2.3, “The General Query Log”.
This variable is deprecated as of MySQL 5.1.29 and is removed in MySQL 5.6. Use
general_loginstead. log_bin_trust_function_creatorsCommand-Line Format --log-bin-trust-function-creatorsSystem Variable Name log_bin_trust_function_creatorsVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault FALSEThis 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
SUPERprivilege in addition to theCREATE ROUTINEorALTER ROUTINEprivilege. A setting of 0 also enforces the restriction that a function must be declared with theDETERMINISTICcharacteristic, or with theREADS SQL DATAorNO SQLcharacteristic. 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 19.7, “Binary Logging of Stored Programs”.log_bin_trust_routine_creatorsThis is the old name for
log_bin_trust_function_creators. This variable is deprecated and is removed in MySQL 5.5.-
Command-Line Format --log-error[=file_name]System Variable Name log_errorVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe location of the error log, or empty if the server is writing error message to the standard error output. See Section 5.2.2, “The Error Log”.
-
Introduced 5.1.6 Command-Line Format --log-output=nameSystem Variable Name log_outputVariable Scope Global Dynamic Variable Yes Permitted Values Type setDefault FILEValid Values TABLEFILENONEThe destination for general query log and slow query log output. The value can be a comma-separated list of one or more of the words
TABLE(log to tables),FILE(log to files), orNONE(do not log to tables or files). The default value isFILE.NONE, if present, takes precedence over any other specifiers. If the value isNONElog entries are not written even if the logs are enabled. If the logs are not enabled, no logging occurs even if the value oflog_outputis notNONE. For more information, see Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”. This variable was added in MySQL 5.1.6. -
Command-Line Format --log-queries-not-using-indexesSystem Variable (>= 5.1.11) Name log_queries_not_using_indexesVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFWhether queries that do not use indexes are logged to the slow query log. See Section 5.2.5, “The Slow Query Log”. This variable was added in MySQL 5.1.11.
-
Deprecated 5.1.29, by slow-query-log Command-Line Format --log-slow-queries[=name]System Variable (<= 5.1.22) Name log_slow_queriesVariable Scope Global Dynamic Variable No System Variable (>= 5.1.23) Name log_slow_queriesVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanWhether slow queries should be logged. “Slow” is determined by the value of the
long_query_timevariable. See Section 5.2.5, “The Slow Query Log”.This variable is deprecated as of MySQL 5.1.29 and is removed in MySQL 5.6. Use
slow_query_loginstead. -
Command-Line Format --log-warnings[=#]System Variable Name log_warningsVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 1Min Value 0Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 1Min Value 0Max Value 18446744073709547520Whether 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. As of MySQL 5.1.38, the server logs messages about statements that are unsafe for statement-based logging if the value is greater than 0. Aborted connections and access-denied errors for new connection attempts are logged if the value is greater than 1.
-
Command-Line Format --long_query_time=#System Variable Name long_query_timeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type numericDefault 10Min Value 0If a query takes longer than this many seconds, the server increments the
Slow_queriesstatus variable. If the slow query log is enabled, 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 default value oflong_query_timeis 10. Beginning with MySQL 5.1.21, the minimum is 0, and the value can be specified to a resolution of microseconds. For logging to a file, times are written including the microseconds part. For logging to tables, only integer times are written; the microseconds part is ignored. Prior to MySQL 5.1.21, the minimum value is 1, and the value for this variable must be an integer. See Section 5.2.5, “The Slow Query Log”. -
Command-Line Format --low-priority-updatesSystem Variable Name low_priority_updatesVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault FALSEIf set to
1, allINSERT,UPDATE,DELETE, andLOCK TABLE WRITEstatements wait until there is no pendingSELECTorLOCK TABLE READon the affected table. This affects only storage engines that use only table-level locking (such asMyISAM,MEMORY, andMERGE). This variable previously was namedsql_low_priority_updates. -
System Variable Name lower_case_file_systemVariable Scope Global Dynamic Variable No Permitted Values Type booleanThis variable describes the case sensitivity of file names on the file system where the data directory is located.
OFFmeans file names are case sensitive,ONmeans 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. -
Command-Line Format --lower_case_table_names[=#]System Variable Name lower_case_table_namesVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 0Min Value 0Max Value 2If 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_namesto 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 anINSERT INTO ... SELECT ... FROMoperation with the wrongtbl_nametbl_nameletter case. WithMyISAM, accessing table names using different letter cases could cause index corruption.If you are using
InnoDBtables, you should set this variable to 1 on all platforms to force names to be converted to lowercase. Prior to MySQL Cluster NDB 6.3.35, MySQL Cluster NDB 7.0.15, and MySQL Cluster NDB 7.1.4, this is also true for tables using theNDBstorage engine.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_nameson 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.38, “Replication and Variables”. -
Command-Line Format --max_allowed_packet=#System Variable Name max_allowed_packetVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 1048576Min Value 1024Max Value 1073741824The maximum size of one packet or any generated/intermediate string.
The packet message buffer is initialized to
net_buffer_lengthbytes, but can grow up tomax_allowed_packetbytes when needed. This value by default is small, to catch large (possibly incorrect) packets.You must increase this value if you are using large
BLOBcolumns or long strings. It should be as big as the largestBLOByou want to use. The protocol limit formax_allowed_packetis 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_packetvariable, you should also change the buffer size on the client side if your client program permits it. The defaultmax_allowed_packetvalue 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 settingmax_allowed_packeton the command line or in an option file.As of MySQL 5.1.31, the session value of this variable is read only. Before 5.1.31, 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_packetvalue. (The global value could be less than the session value if the global value is changed after the client connects.) -
Command-Line Format --max_connect_errors=#System Variable Name max_connect_errorsVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 10Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 10Min Value 1Max Value 18446744073709547520If 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 HOSTSstatement or execute a mysqladmin flush-hosts command. If a connection is established successfully within fewer thanmax_connect_errorsattempts 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. -
Command-Line Format --max_connections=#System Variable Name max_connectionsVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.1.14) Type integerDefault 100Min Value 1Max Value 16384Permitted Values (>= 5.1.15, <= 5.1.16) Type integerDefault 151Min Value 1Max Value 16384Permitted Values (>= 5.1.17) Type integerDefault 151Min Value 1Max Value 100000The maximum permitted number of simultaneous client connections. By default, this is 151, beginning with MySQL 5.1.15. (Previously, the default was 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.
-
Command-Line Format --max_delayed_threads=#System Variable Name max_delayed_threadsVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 20Min Value 0Max Value 16384Do not start more than this number of threads to handle
INSERT DELAYEDstatements. If you try to insert data into a new table after allINSERT DELAYEDthreads are in use, the row is inserted as if theDELAYEDattribute was not specified. If you set this to 0, MySQL never creates a thread to handleDELAYEDrows; in effect, this disablesDELAYEDentirely.For the
SESSIONvalue of this variable, the only valid values are 0 or theGLOBALvalue. -
Command-Line Format --max_error_count=#System Variable Name max_error_countVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 64Min Value 0Max Value 65535The maximum number of error, warning, and note messages to be stored for display by the
SHOW ERRORSandSHOW WARNINGSstatements. -
Command-Line Format --max_heap_table_size=#System Variable Name max_heap_table_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 16777216Min Value 16384Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 16777216Min Value 16384Max Value 1844674407370954752This variable sets the maximum size to which user-created
MEMORYtables are permitted to grow. The value of the variable is used to calculateMEMORYtableMAX_ROWSvalues. Setting this variable has no effect on any existingMEMORYtable, unless the table is re-created with a statement such asCREATE TABLEor altered withALTER TABLEorTRUNCATE TABLE. A server restart also sets the maximum size of existingMEMORYtables to the globalmax_heap_table_sizevalue.This variable is also used in conjunction with
tmp_table_sizeto limit the size of internal in-memory tables. See Section 8.4.4, “Internal Temporary Table Use in MySQL”.max_heap_table_sizeis not replicated. See Section 16.4.1.22, “Replication and MEMORY Tables”, and Section 16.4.1.38, “Replication and Variables”, for more information. -
System Variable Name max_insert_delayed_threadsVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerThis variable is a synonym for
max_delayed_threads. -
Command-Line Format --max_join_size=#System Variable Name max_join_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 4294967295Min Value 1Max Value 4294967295Do not permit statements that probably need to examine more than
max_join_sizerows (for single-table statements) or row combinations (for multiple-table statements) or that are likely to do more thanmax_join_sizedisk 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 aWHEREclause, that take a long time, or that return millions of rows.Setting this variable to a value other than
DEFAULTresets the value ofsql_big_selectsto0. If you set thesql_big_selectsvalue again, themax_join_sizevariable 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. -
Command-Line Format --max_length_for_sort_data=#System Variable Name max_length_for_sort_dataVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 1024Min Value 4Max Value 8388608The cutoff on the size of index values that determines which
filesortalgorithm to use. See Section 8.2.1.11, “ORDER BY Optimization”. -
Introduced 5.1.57 Deprecated 5.1.57 Command-Line Format --max_long_data_size=#System Variable Name max_long_data_sizeVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 1048576Min Value 1024Max Value 4294967295The maximum size of parameter values that can be sent with the
mysql_stmt_send_long_data()C API function. If not set at server startup, the default is the value of themax_allowed_packetsystem variable. This variable is deprecated. In MySQL 5.6, it is removed and the maximum parameter size is controlled bymax_allowed_packet. -
Introduced 5.1.10 Command-Line Format --max_prepared_stmt_count=#System Variable Name max_prepared_stmt_countVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 16382Min Value 0Max Value 1048576This 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.1.10.
-
Command-Line Format --max_relay_log_size=#System Variable Name max_relay_log_sizeVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Max Value 1073741824If 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_sizeis 0, the server usesmax_binlog_sizefor both the binary log and the relay log. Ifmax_relay_log_sizeis greater than 0, it constrains the size of the relay log, which enables you to have different sizes for the two logs. You must setmax_relay_log_sizeto between 4096 bytes and 1GB (inclusive), or to 0. The default value is 0. See Section 16.2.1, “Replication Implementation Details”. -
Command-Line Format --max_seeks_for_key=#System Variable Name max_seeks_for_keyVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 4294967295Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 18446744073709547520Min Value 1Max Value 18446744073709547520Limit 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.23, “SHOW INDEX Syntax”). By setting this to a low value (say, 100), you can force MySQL to prefer indexes instead of table scans.
-
Command-Line Format --max_sort_length=#System Variable Name max_sort_lengthVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 1024Min Value 4Max Value 8388608The number of bytes to use when sorting data values. The server uses only the first
max_sort_lengthbytes of each value and ignores the rest. Consequently, values that differ only after the firstmax_sort_lengthbytes compare as equal forGROUP BY,ORDER BY, andDISTINCToperations. -
Command-Line Format --max_sp_recursion_depth[=#]System Variable Name max_sp_recursion_depthVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 0Max Value 255The 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 ofthread_stackat server startup. This variable is unused.
-
Command-Line Format --max_user_connections=#System Variable Name max_user_connectionsVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Max Value 4294967295The maximum number of simultaneous connections permitted to any given MySQL user account. A value of 0 (the default) means “no limit.”
This variable has a global value that can be set at server startup or runtime. 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_CONNECTIONSresource limit, the sessionmax_user_connectionsvalue is set to that limit.Otherwise, the session
max_user_connectionsvalue is set to the global value.
Account resource limits are specified using the
GRANTstatement. See Section 6.3.4, “Setting Account Resource Limits”, and Section 13.7.1.3, “GRANT Syntax”. -
Command-Line Format --max_write_lock_count=#System Variable Name max_write_lock_countVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 4294967295Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 18446744073709547520Min Value 1Max Value 18446744073709547520After this many write locks, permit some pending read lock requests to be processed in between.
-
Introduced 5.1.21 Command-Line Format --min-examined-row-limit=#System Variable Name min_examined_row_limitVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 0Min Value 0Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 0Min Value 0Max Value 18446744073709547520Queries that examine fewer than this number of rows are not logged to the slow query log. This variable was added in MySQL 5.1.21.
-
Command-Line Format --multi_range_count=#System Variable Name multi_range_countVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 256Min Value 1Max Value 4294967295The 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
NDBCLUSTERtable 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 is deprecated in MySQL 5.1, and is no longer supported in MySQL 5.5, in which arbitrarily long lists of ranges can be processed.
-
Command-Line Format --myisam_data_pointer_size=#System Variable Name myisam_data_pointer_sizeVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 6Min Value 2Max Value 7The default pointer size in bytes, to be used by
CREATE TABLEforMyISAMtables when noMAX_ROWSoption is specified. This variable cannot be less than 2 or larger than 7. The default value is 6. See Section B.5.2.12, “The table is full”. -
Command-Line Format --myisam_max_sort_file_size=#System Variable Name myisam_max_sort_file_sizeVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 2147483648Permitted Values (64-bit platforms) Type integerDefault 9223372036854775807The maximum size of the temporary file that MySQL is permitted to use while re-creating a
MyISAMindex (duringREPAIR TABLE,ALTER TABLE, orLOAD 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
MyISAMindex 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. -
Introduced 5.1.43 Command-Line Format --myisam_mmap_size=#System Variable Name myisam_mmap_sizeVariable Scope Global Dynamic Variable No Permitted Values (32-bit platforms) Type integerDefault 4294967295Min Value 7Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 18446744073709547520Min Value 7Max Value 18446744073709547520The maximum amount of memory to use for memory mapping compressed
MyISAMfiles. If many compressedMyISAMtables are used, the value can be decreased to reduce the likelihood of memory-swapping problems. This variable was added in MySQL 5.1.43. -
System Variable Name myisam_recover_optionsVariable Scope Global Dynamic Variable No The value of the
--myisam-recoveroption. See Section 5.1.3, “Server Command Options”. -
Command-Line Format --myisam_repair_threads=#System Variable Name myisam_repair_threadsVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 1Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 1Min Value 1Max Value 18446744073709547520If this value is greater than 1,
MyISAMtable indexes are created in parallel (each index in its own thread) during theRepair by sortingprocess. The default value is 1.NoteMulti-threaded repair is still beta-quality code.
-
Command-Line Format --myisam_sort_buffer_size=#System Variable Name myisam_sort_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (Windows) Type integerDefault 8388608Min Value 4096Max Value 4294967295Permitted Values (Other, 32-bit platforms) Type integerDefault 8388608Min Value 4096Max Value 4294967295Permitted Values (Other, 64-bit platforms) Type integerDefault 8388608Min Value 4096Max Value 18446744073709547520The size of the buffer that is allocated when sorting
MyISAMindexes during aREPAIR TABLEor when creating indexes withCREATE INDEXorALTER TABLE.The maximum permissible setting for
myisam_sort_buffer_sizeis 4GB−1. As of MySQL 5.1.23, larger values are permitted for 64-bit platforms (except 64-bit Windows, for which large values are truncated to 4GB−1 with a warning). -
Command-Line Format --myisam_stats_method=nameSystem Variable Name myisam_stats_methodVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type enumerationDefault nulls_unequalValid Values nulls_equalnulls_unequalnulls_ignoredHow the server treats
NULLvalues when collecting statistics about the distribution of index values forMyISAMtables. This variable has three possible values,nulls_equal,nulls_unequal, andnulls_ignored. Fornulls_equal, allNULLindex values are considered equal and form a single value group that has a size equal to the number ofNULLvalues. Fornulls_unequal,NULLvalues are considered unequal, and eachNULLforms a distinct value group of size 1. Fornulls_ignored,NULLvalues are ignored.The method that is used for generating table statistics influences how the optimizer chooses indexes for query execution, as described in Section 8.3.7, “InnoDB and MyISAM Index Statistics Collection”.
Any unique prefix of a valid value may be used to set the value of this variable.
-
Introduced 5.1.4 Command-Line Format --myisam_use_mmapSystem Variable Name myisam_use_mmapVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFUse memory mapping for reading and writing
MyISAMtables. This variable was added in MySQL 5.1.4. -
System Variable Name named_pipeVariable Scope Global Dynamic Variable No Platform Specific Windows Permitted Values (Windows) Type booleanDefault OFF(Windows only.) Indicates whether the server supports connections over named pipes.
-
Command-Line Format --net_buffer_length=#System Variable Name net_buffer_lengthVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 16384Min Value 1024Max Value 1048576Each client thread is associated with a connection buffer and result buffer. Both begin with a size given by
net_buffer_lengthbut are dynamically enlarged up tomax_allowed_packetbytes as needed. The result buffer shrinks tonet_buffer_lengthafter 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_lengthcan be set is 1MB.As of MySQL 5.1.31, the session value of this variable is read only. Before 5.1.31, setting the session value is permitted but has no effect.
-
Command-Line Format --net_read_timeout=#System Variable Name net_read_timeoutVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 30Min Value 1The number of seconds to wait for more data from a connection before aborting the read. Before MySQL 5.1.41, 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_timeoutis the timeout value controlling when to abort. When the server is writing to the client,net_write_timeoutis the timeout value controlling when to abort. See alsoslave_net_timeout.On Linux, the
NO_ALARMbuild flag affects timeout behavior as indicated in the description of thenet_retry_countsystem variable. -
Command-Line Format --net_retry_count=#System Variable Name net_retry_countVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 10Min Value 1Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 10Min Value 1Max Value 18446744073709547520If 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_ALARMbuild flag (-DNO_ALARM) modifies how the binary treats bothnet_read_timeoutandnet_write_timeout. With this flag enabled, neither timer cancels the current statement until after the failing connection has been waited on an additionalnet_retry_counttimes. This means that the effective timeout value becomes(timeout setting) × (net_retry_count+1). -
Command-Line Format --net_write_timeout=#System Variable Name net_write_timeoutVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 60Min Value 1The number of seconds to wait for a block to be written to a connection before aborting the write. Before MySQL 5.1.41, 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_ALARMbuild flag affects timeout behavior as indicated in the description of thenet_retry_countsystem variable. -
Command-Line Format --newSystem Variable Name newVariable Scope Global, Session Dynamic Variable Yes Disabled by skip-newPermitted Values Type booleanDefault FALSEThis 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.In MySQL Cluster 5.1.12 and later, setting this variable to
ONmakes it possible to employ partitioning types other thanKEYorLINEAR KEYwithNDBtables. This feature is experimental only, and not supported in production. For additional information, see User-defined partitioning and the NDB storage engine (MySQL Cluster). -
Introduced 5.1.18 Command-Line Format --oldSystem Variable Name oldVariable Scope Global Dynamic Variable No oldis a compatibility variable. It is disabled by default, but can be enabled at startup to revert the server to behaviors present in older versions.When
oldis enabled, it changes the default scope of index hints to that used prior to MySQL 5.1.17. That is, index hints with noFORclause apply only to how indexes are used for row retrieval and not to resolution ofORDER BYorGROUP BYclauses. (See Section 8.9.3, “Index Hints”.) Take care about enabling this in a replication setup. With statement-based binary logging, having different modes for the master and slaves might lead to replication errors.This variable was added as
old_modein MySQL 5.1.17 and renamed tooldin MySQL 5.1.18. -
Command-Line Format --old-alter-tableSystem Variable Name old_alter_tableVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault OFFWhen this variable is enabled, the server does not use the optimized method of processing an
ALTER TABLEoperation. It reverts to using a temporary table, copying over the data, and then renaming the temporary table to the original, as used by MySQL 5.0 and earlier. For more information on the operation ofALTER TABLE, see Section 13.1.7, “ALTER TABLE Syntax”. -
System Variable Name old_passwordsVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault 0This variable controls the password hashing method used by the
PASSWORD()function. It also influences password hashing performed byCREATE USERandGRANTstatements that specify a password using anIDENTIFIED BYclause.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 (orON) causes password encryption to use the older pre-4.1 format.If
old_passwords=1,PASSWORD(returns the same value asstr)OLD_PASSWORD(. The latter function is not affected by the value ofstr)old_passwords.For information about hashing formats, see Section 6.1.2.4, “Password Hashing in MySQL”.
This is not a variable, but it can be used when setting some variables. It is described in Section 13.7.4, “SET Syntax”.
-
Command-Line Format --open-files-limit=#System Variable Name open_files_limitVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 0Min Value 0Max Value platform dependentThe 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-limitoption to mysqld or mysqld_safe. The value is 0 on systems where MySQL cannot change the number of open files. -
Command-Line Format --optimizer_prune_level[=#]System Variable Name optimizer_prune_levelVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault 1Controls 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.
-
Command-Line Format --optimizer_search_depth[=#]System Variable Name optimizer_search_depthVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 62Min Value 0Max Value 63The 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. The value of 63 is deprecated and will be treated as invalid in a future MySQL release.
-
Introduced 5.1.34 Command-Line Format --optimizer_switch=valueSystem Variable Name optimizer_switchVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type setValid Values index_merge={on|off}index_merge_intersection={on|off}index_merge_sort_union={on|off}index_merge_union={on|off}The
optimizer_switchsystem variable enables control over optimizer behaviors. The value of this variable is a set of flags, each of which has a value ofonoroffto indicate whether the corresponding optimizer behavior is enabled or disabled. This variable has global and session values and can be changed at runtime. The global default can be set at server startup.To see the current set of optimizer flags, select the variable value:
mysql>
SELECT @@optimizer_switch\G*************************** 1. row *************************** @@optimizer_switch: index_merge=on,index_merge_union=on, index_merge_sort_union=on,index_merge_intersection=onFor more information about the syntax of this variable and the optimizer behaviors that it controls, see Section 8.9.2, “Controlling Switchable Optimizations”.
-
Command-Line Format --pid-file=file_nameSystem Variable Name pid_fileVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe path name of the process ID (PID) file. This variable can be set with the
--pid-fileoption. -
Introduced 5.1.2 Command-Line Format --plugin_dir=dir_nameSystem Variable Name plugin_dirVariable Scope Global Dynamic Variable No Permitted Values (<= 5.1.1) Type directory nameDefault Permitted Values (Windows, >= 5.1.2) Type directory nameDefault BASEDIR/lib/pluginPermitted Values (Other, >= 5.1.2) Type directory nameDefault BASEDIR/lib/mysql/pluginThe path name of the plugin directory. This variable was added in MySQL 5.1.2.
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 makingplugin_dirread only to the server or by setting--secure-file-privto a directory whereSELECTwrites can be made safely. -
Command-Line Format --port=#System Variable Name portVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 3306Min Value 0Max Value 65535The number of the port on which the server listens for TCP/IP connections. This variable can be set with the
--portoption. -
Command-Line Format --preload_buffer_size=#System Variable Name preload_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 32768Min Value 1024Max Value 1073741824The size of the buffer that is allocated when preloading indexes.
-
Introduced 5.1.10 Removed 5.1.13 System Variable (>= 5.1.10, <= 5.1.13) Name prepared_stmt_countVariable Scope Global Dynamic Variable No Permitted Values Type integerThe current number of prepared statements. (The maximum number of statements is given by the
max_prepared_stmt_countsystem variable.) This variable was added in MySQL 5.1.10. In MySQL 5.1.14, it was converted to the globalPrepared_stmt_countstatus variable. If set to 0 or
OFF(the default), statement profiling is disabled. If set to 1 orON, statement profiling is enabled and theSHOW PROFILEandSHOW PROFILESstatements provide access to profiling information. See Section 13.7.5.33, “SHOW PROFILES Syntax”. This variable was added in MySQL 5.1.24.The number of statements for which to maintain profiling information if
profilingis enabled. The default value is 15. The maximum value is 100. Setting the value to 0 effectively disables profiling. See Section 13.7.5.33, “SHOW PROFILES Syntax”. This variable was added in MySQL 5.1.24.-
System Variable Name protocol_versionVariable Scope Global Dynamic Variable No Permitted Values Type integerThe version of the client/server protocol used by the MySQL server.
-
System Variable Name pseudo_thread_idVariable Scope Session Dynamic Variable Yes Permitted Values Type integerThis variable is for internal server use.
-
Command-Line Format --query_alloc_block_size=#System Variable Name query_alloc_block_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 8192Min Value 1024Max Value 4294967295Block Size 1024Permitted Values (64-bit platforms) Type integerDefault 8192Min Value 1024Max Value 18446744073709547520Block Size 1024The 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.
-
Command-Line Format --query_cache_limit=#System Variable Name query_cache_limitVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 1048576Min Value 0Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 1048576Min Value 0Max Value 18446744073709547520Do not cache results that are larger than this number of bytes. The default value is 1MB.
-
Command-Line Format --query_cache_min_res_unit=#System Variable Name query_cache_min_res_unitVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 4096Min Value 512Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 4096Min Value 512Max Value 18446744073709547520The 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”.
-
Command-Line Format --query_cache_size=#System Variable Name query_cache_sizeVariable Scope Global Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 0Min Value 0Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 0Min Value 0Max Value 18446744073709547520The 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_sizebytes of memory are allocated even ifquery_cache_typeis 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_sizetoo small, a warning will occur, as described in Section 8.10.3.3, “Query Cache Configuration”. -
Command-Line Format --query_cache_type=#System Variable Name query_cache_typeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type enumerationDefault 1Valid Values 012Set the query cache type. Setting the
GLOBALvalue sets the type for all clients that connect thereafter. Individual clients can set theSESSIONvalue to affect their own use of the query cache. Possible values are shown in the following table.Option Description 0orOFFDo 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_sizeto 0.1orONCache all cacheable query results except for those that begin with SELECT SQL_NO_CACHE.2orDEMANDCache 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.
-
Command-Line Format --query_cache_wlock_invalidateSystem Variable Name query_cache_wlock_invalidateVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault FALSENormally, when one client acquires a
WRITElock on aMyISAMtable, 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 aWRITElock 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. -
Command-Line Format --query_prealloc_size=#System Variable Name query_prealloc_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 8192Min Value 8192Max Value 4294967295Block Size 1024Permitted Values (64-bit platforms) Type integerDefault 8192Min Value 8192Max Value 18446744073709547520Block Size 1024The 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_sizevalue might be helpful in improving performance, because it can reduce the need for the server to perform memory allocation during query execution operations. The
rand_seed1andrand_seed2variables exist as session variables only, and can be set but not read. Beginning with MySQL 5.1.18, the variables—but not their values—are shown in the output ofSHOW VARIABLES.The purpose of these variables is to support replication of the
RAND()function. For statements that invokeRAND(), 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 variablesrand_seed1andrand_seed2so thatRAND()on the slave generates the same value as on the master.See the description for
rand_seed1.-
Command-Line Format --range_alloc_block_size=#System Variable Name range_alloc_block_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 4096Min Value 4096Max Value 4294967295Block Size 1024The size of blocks that are allocated when doing range optimization.
-
Command-Line Format --read_buffer_size=#System Variable Name read_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 131072Min Value 8200Max Value 2147479552Each thread that does a sequential scan for a
MyISAMtable 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.This option is also used in the following context for all storage engines:
For caching the indexes in a temporary file (not a temporary table), when sorting rows for
ORDER BY.For bulk insert into partitions.
For caching results of nested queries.
and in one other storage engine-specific way: to determine the memory block size for
MEMORYtables.The maximum permissible setting for
read_buffer_sizeis 2GB.For more information about memory use during different operations, see Section 8.12.5.1, “How MySQL Uses Memory”.
-
Command-Line Format --read_onlySystem Variable Name read_onlyVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFWhen the
read_onlysystem variable is enabled, the server permits no client updates except from users who have theSUPERprivilege. This variable is disabled by default.Even with
read_onlyenabled, 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_onlyon slave servers to ensure that slaves accept updates only from the master server and not from clients.Use of
ANALYZE TABLEorOPTIMIZE TABLEstatements. 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
TEMPORARYtables.Inserts into the log tables (
mysql.general_logandmysql.slow_log; see Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”).
read_onlyexists only as aGLOBALvariable, so changes to its value require theSUPERprivilege. Changes toread_onlyon 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.ImportantAs of MySQL 5.1, enabling
read_onlyprevents users not having theSUPERprivilege from using account-management statements such asCREATE USERorSET 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.As of MySQL 5.1.15, the following conditions apply to attempts to enable
read_only:The attempt fails and an error occurs if you have any explicit locks (acquired with
LOCK TABLES) or have a pending transaction.The attempt blocks while other clients hold explicit table locks or have pending transactions, until the locks are released and the transactions end. While the attempt to enable
read_onlyis pending, requests by other clients for table locks or to begin transactions also block untilread_onlyhas been set.read_onlycan be enabled while you hold a global read lock (acquired withFLUSH TABLES WITH READ LOCK) because that does not involve table locks.
-
Command-Line Format --read_rnd_buffer_size=#System Variable Name read_rnd_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerDefault 262144Min Value 8200Max Value 2147483647When reading rows from a
MyISAMtable 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 improveORDER BYperformance 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_sizeis 2GB.For more information about memory use during different operations, see Section 8.12.5.1, “How MySQL Uses Memory”.
-
Command-Line Format --relay_log_purgeSystem Variable Name relay_log_purgeVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault TRUEDisables or enables automatic purging of relay log files as soon as they are not needed any more. The default value is 1 (
ON). -
Command-Line Format --relay_log_space_limit=#System Variable Name relay_log_space_limitVariable Scope Global Dynamic Variable No Permitted Values (32-bit platforms) Type integerDefault 0Min Value 0Max Value 4294967295Permitted Values (64-bit platforms) Type integerDefault 0Min Value 0Max Value 18446744073709547520The maximum amount of space to use for all relay logs.
-
Command-Line Format --report-host=host_nameSystem Variable (>= 5.1.24) Name report_hostVariable Scope Global Dynamic Variable No Permitted Values Type stringThe value of the
--report-hostoption. This variable was added in MySQL 5.1.24. -
Command-Line Format --report-password=nameSystem Variable (>= 5.1.24) Name report_passwordVariable Scope Global Dynamic Variable No Permitted Values Type stringThe value of the
--report-passwordoption. Not the same as the password for the MySQL replication user account. This variable was added in MySQL 5.1.24. -
Command-Line Format --report-port=#System Variable (>= 5.1.24) Name report_portVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 3306Min Value 0Max Value 65535The value of the
--report-portoption. This variable was added in MySQL 5.1.24. -
Command-Line Format --report-user=nameSystem Variable (>= 5.1.24) Name report_userVariable Scope Global Dynamic Variable No Permitted Values Type stringThe value of the
--report-useroption. This variable was added in MySQL 5.1.24. -
Command-Line Format --secure-authSystem Variable Name secure_authVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFIf 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”.
-
Introduced 5.1.17 Command-Line Format --secure-file-priv=dir_nameSystem Variable Name secure_file_privVariable Scope Global Dynamic Variable No Permitted Values Type stringDefault emptyValid Values emptydirnameThis variable is used to limit the effect of data import and export operations, such as those performed by the
LOAD DATAandSELECT ... INTO OUTFILEstatements and theLOAD_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.1.17.
-
Command-Line Format --server-id=#System Variable Name server_idVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Max Value 4294967295The server ID, used in replication to give each master and slave a unique identity. This variable is set by the
--server-idoption. 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. -
Command-Line Format --shared_memory[={0,1}]System Variable Name shared_memoryVariable Scope Global Dynamic Variable No Platform Specific Windows Permitted Values Type booleanDefault FALSE(Windows only.) Whether the server permits shared-memory connections.
-
Command-Line Format --shared_memory_base_name=nameSystem Variable Name shared_memory_base_nameVariable Scope Global Dynamic Variable No Platform Specific Windows Permitted Values Type stringDefault MYSQL(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. -
Command-Line Format --skip-external-lockingSystem Variable Name skip_external_lockingVariable Scope Global Dynamic Variable No Permitted Values Type booleanDefault ONThis is
OFFif mysqld uses external locking (system locking),ONif external locking is disabled. This affects onlyMyISAMtable access.This variable is set by the
--external-lockingor--skip-external-lockingoption. External locking is disabled by default.External locking affects only
MyISAMtable access. For more information, including conditions under which it can and cannot be used, see Section 8.11.4, “External Locking”. -
Command-Line Format --skip-name-resolveSystem Variable (>= 5.1.46) Name skip_name_resolveVariable Scope Global Dynamic Variable No Permitted Values Type booleanDefault OFFThis variable is set from the value of the
--skip-name-resolveoption. If it isOFF, mysqld resolves host names when checking client connections. If it isON, mysqld uses only IP numbers; in this case, allHostcolumn values in the grant tables must be IP addresses orlocalhost. See Section 8.12.6.2, “DNS Lookup Optimization and the Host Cache”.This variable was added in MySQL 5.1.46.
-
Command-Line Format --skip-networkingSystem Variable Name skip_networkingVariable Scope Global Dynamic Variable No This is
ONif 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 toON. This variable can be set toONwith the--skip-networkingoption. -
Command-Line Format --skip-show-databaseSystem Variable Name skip_show_databaseVariable Scope Global Dynamic Variable No This prevents people from using the
SHOW DATABASESstatement if they do not have theSHOW DATABASESprivilege. This can improve security if you have concerns about users being able to see databases belonging to other users. Its effect depends on theSHOW DATABASESprivilege: If the variable value isON, theSHOW DATABASESstatement is permitted only to users who have theSHOW DATABASESprivilege, and the statement displays all database names. If the value isOFF,SHOW DATABASESis permitted to all users, but displays the names of only those databases for which the user has theSHOW DATABASESor other privilege. (Note that any global privilege is considered a privilege for the database.) -
Command-Line Format --slow_launch_time=#System Variable Name slow_launch_timeVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 2If creating a thread takes longer than this many seconds, the server increments the
Slow_launch_threadsstatus variable. -
Introduced 5.1.12 Command-Line Format --slow-query-log(>= 5.1.29)System Variable Name slow_query_logVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFWhether the slow query log is enabled. The value can be 0 (or
OFF) to disable the log or 1 (orON) to enable the log. The default value depends on whether the--slow_query_logoption is given (--log-slow-queriesbefore MySQL 5.1.29). The destination for log output is controlled by thelog_outputsystem variable; if that value isNONE, no log entries are written even if the log is enabled. Theslow_query_logvariable was added in MySQL 5.1.12.“Slow” is determined by the value of the
long_query_timevariable. See Section 5.2.5, “The Slow Query Log”. -
Introduced 5.1.12 Command-Line Format --slow-query-log-file=file_nameSystem Variable Name slow_query_log_fileVariable Scope Global Dynamic Variable Yes Permitted Values Type file nameDefault host_name-slow.logThe name of the slow query log file. The default value is
, but the initial value can be changed with thehost_name-slow.log--slow_query_log_fileoption (--log-slow-queriesbefore MySQL 5.1.29). This variable was added in MySQL 5.1.12. -
Command-Line Format --socket={file_name|pipe_name}System Variable Name socketVariable Scope Global Dynamic Variable No Permitted Values Type stringDefault /tmp/mysql.sockOn 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/mysqlfor 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). -
Command-Line Format --sort_buffer_size=#System Variable Name sort_buffer_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (<= 5.1.22) Type integerDefault 2097144Min Value 32768Max Value 4294967295Permitted Values (Windows, >= 5.1.23) Type integerDefault 2097144Min Value 32768Max Value 4294967295Permitted Values (Other, 32-bit platforms, >= 5.1.23) Type integerDefault 2097144Min Value 32768Max Value 4294967295Permitted Values (Other, 64-bit platforms, >= 5.1.23) Type integerDefault 2097144Min Value 32768Max Value 18446744073709551615Each session that needs to do a sort allocates a buffer of this size.
sort_buffer_sizeis 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_passesper second inSHOW GLOBAL STATUSoutput, you can consider increasing thesort_buffer_sizevalue to speed upORDER BYorGROUP BYoperations 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_sizeis 4GB−1. As of MySQL 5.1.23, larger values are permitted for 64-bit platforms (except 64-bit Windows, for which large values are truncated to 4GB−1 with a warning). -
System Variable Name sql_auto_is_nullVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanDefault 1If this variable is set to 1 (the default), then after a statement that successfully inserts an automatically generated
AUTO_INCREMENTvalue, you can find that value by issuing a statement of the following form:SELECT * FROM
tbl_nameWHEREauto_colIS NULLIf 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.14, “Information Functions”. If noAUTO_INCREMENTvalue was successfully inserted, theSELECTstatement returns no row.The behavior of retrieving an
AUTO_INCREMENTvalue by using anIS NULLcomparison is used by some ODBC programs, such as Access. See Obtaining Auto-Increment Values. This behavior can be disabled by settingsql_auto_is_nullto 0. -
System Variable Name sql_big_selectsVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanDefault 1If set to 0, MySQL aborts
SELECTstatements 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 ofmax_join_size). This is useful when an inadvisableWHEREstatement has been issued. The default value for a new connection is 1, which permits allSELECTstatements.If you set the
max_join_sizesystem variable to a value other thanDEFAULT,sql_big_selectsis set to 0. -
System Variable Name sql_buffer_resultVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanDefault 0If set to 1,
sql_buffer_resultforces results fromSELECTstatements 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. -
System Variable Name sql_log_binVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanIf set to 0, no logging is done to the binary log for the client. The client must have the
SUPERprivilege to set this option. The default value is 1. -
System Variable Name sql_log_offVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanDefault 0If set to 1, no logging is done to the general query log for this client. The client must have the
SUPERprivilege to set this option. The default value is 0. -
Deprecated 5.0.0, by sql_log_bin System Variable Name sql_log_updateVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanThis variable is deprecated, and is mapped to
sql_log_bin. It is removed in MySQL 5.5. -
Command-Line Format --sql-mode=nameSystem Variable Name sql_modeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type setDefault ''Valid Values ALLOW_INVALID_DATESANSI_QUOTESERROR_FOR_DIVISION_BY_ZEROHIGH_NOT_PRECEDENCEIGNORE_SPACENO_AUTO_CREATE_USERNO_AUTO_VALUE_ON_ZERONO_BACKSLASH_ESCAPESNO_DIR_IN_CREATENO_ENGINE_SUBSTITUTIONNO_FIELD_OPTIONSNO_KEY_OPTIONSNO_TABLE_OPTIONSNO_UNSIGNED_SUBTRACTIONNO_ZERO_DATENO_ZERO_IN_DATEONLY_FULL_GROUP_BYPAD_CHAR_TO_FULL_LENGTHPIPES_AS_CONCATREAL_AS_FLOATSTRICT_ALL_TABLESSTRICT_TRANS_TABLESThe current server SQL mode, which can be set dynamically. For details, see Section 5.1.7, “Server SQL Modes”.
NoteMySQL 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.
If set to 1 (the default), warnings of
Notelevel incrementwarning_countand the server records them. If set to 0,Notewarnings do not incrementwarning_countand 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.If set to 1 (the default), the server quotes identifiers for
SHOW CREATE TABLEandSHOW CREATE DATABASEstatements. 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.12, “SHOW CREATE TABLE Syntax”, and Section 13.7.5.8, “SHOW CREATE DATABASE Syntax”.If set to 1, MySQL aborts
UPDATEorDELETEstatements that do not use a key in theWHEREclause or aLIMITclause. (Specifically,UPDATEstatements must have aWHEREclause that uses a key or aLIMITclause, or both.DELETEstatements must have both.) This makes it possible to catchUPDATEorDELETEstatements where keys are not used properly and that would probably change or delete a large number of rows. The default value is 0.-
System Variable Name sql_select_limitVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type integerThe maximum number of rows to return from
SELECTstatements. 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 ofDEFAULT.If a
SELECThas aLIMITclause, theLIMITtakes precedence over the value ofsql_select_limit. This variable controls whether single-row
INSERTstatements produce an information string if warnings occur. The default is 0. Set the value to 1 to produce an information string.-
Introduced 5.1.11 Command-Line Format --ssl-ca=file_nameSystem Variable Name ssl_caVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe path to a file with a list of trusted SSL CAs. This variable was added in MySQL 5.1.11.
-
Introduced 5.1.11 Command-Line Format --ssl-capath=dir_nameSystem Variable Name ssl_capathVariable Scope Global Dynamic Variable No Permitted Values Type directory nameThe path to a directory that contains trusted SSL CA certificates in PEM format. This variable was added in MySQL 5.1.11.
-
Introduced 5.1.11 Command-Line Format --ssl-cert=file_nameSystem Variable Name ssl_certVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe name of the SSL certificate file to use for establishing a secure connection. This variable was added in MySQL 5.1.11.
-
Introduced 5.1.11 Command-Line Format --ssl-cipher=nameSystem Variable Name ssl_cipherVariable Scope Global Dynamic Variable No Permitted Values Type stringA list of permissible ciphers to use for SSL encryption. This variable was added in MySQL 5.1.11.
-
Introduced 5.1.11 Command-Line Format --ssl-key=file_nameSystem Variable Name ssl_keyVariable Scope Global Dynamic Variable No Permitted Values Type file nameThe name of the SSL key file to use for establishing a secure connection. This variable was added in MySQL 5.1.11.
-
System Variable Name storage_engineVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type enumerationDefault MyISAMThe default storage engine (table type). To set the storage engine at server startup, use the
--default-storage-engineoption. See Section 5.1.3, “Server Command Options”.To see which storage engines are available and enabled, use the
SHOW ENGINESstatement or query theINFORMATION_SCHEMAENGINEStable. -
Command-Line Format --sync-frmSystem Variable Name sync_frmVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault TRUEIf this variable is set to 1, when any nontemporary table is created its
.frmfile is synchronized to disk (usingfdatasync()). This is slower but safer in case of a crash. The default is 1. -
System Variable Name system_time_zoneVariable Scope Global Dynamic Variable No Permitted Values Type stringThe 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 theTZenvironment variable. It also can be specified using the--timezoneoption of the mysqld_safe script.The
system_time_zonevariable differs fromtime_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”. -
Deprecated 5.1.3, by table_open_cache Removed 5.1.3 Command-Line Format --table_cache=#System Variable Name table_cacheVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 64Min Value 1Max Value 524288This is the old name of
table_open_cachebefore MySQL 5.1.3. From 5.1.3 on, usetable_open_cacheinstead. -
Introduced 5.1.3 System Variable Name table_definition_cacheVariable Scope Global Dynamic Variable Yes Permitted Values (<= 5.1.24) Type integerDefault 128Min Value 1Max Value 524288Permitted Values (>= 5.1.25) Type integerDefault 256Min Value 256Max Value 524288The number of table definitions (from
.frmfiles) that can be stored in the definition cache. If you use a large number of tables, you can create a large table definition cache to speed up opening of tables. The table definition cache takes less space and does not use file descriptors, unlike the normal table cache. This variable was added in MySQL 5.1.3. The minimum and default values are 1 and 128 before MySQL 5.1.25. The minimum and default are both 256 as of MySQL 5.1.25. -
Command-Line Format --table_lock_wait_timeout=#System Variable Name table_lock_wait_timeoutVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 50Min Value 1Max Value 1073741824This variable is unused.
-
Introduced 5.1.3 System Variable Name table_open_cacheVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 64Min Value 1Max Value 524288The 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_tablesstatus variable. See Section 5.1.6, “Server Status Variables”. If the value ofOpened_tablesis large and you do not useFLUSH TABLESoften (which just forces all tables to be closed and reopened), then you should increase the value of thetable_open_cachevariable. For more information about the table cache, see Section 8.4.3.1, “How MySQL Opens and Closes Tables”. Before MySQL 5.1.3, this variable is calledtable_cache. -
System Variable Name table_typeVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type enumerationThis variable is a synonym for
storage_engine, which is the preferred name;table_typeis deprecated and is removed in MySQL 5.5. -
Command-Line Format --thread_cache_size=#System Variable Name thread_cache_sizeVariable Scope Global Dynamic Variable Yes Permitted Values Type integerDefault 0Min Value 0Max Value 16384How 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_sizethreads 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 setthread_cache_sizehigh enough so that most new connections use cached threads. By examining the difference between theConnectionsandThreads_createdstatus variables, you can see how efficient the thread cache is. For details, see Section 5.1.6, “Server Status Variables”. -
Command-Line Format --thread_concurrency=#System Variable Name thread_concurrencyVariable Scope Global Dynamic Variable No Permitted Values Type integerDefault 10Min Value 1Max Value 512This 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. -
Introduced 5.1.17 Command-Line Format --thread_handling=nameSystem Variable (>= 5.1.17) Name thread_handlingVariable Scope Global Dynamic Variable No Permitted Values Type enumerationDefault one-thread-per-connectionValid Values no-threadsone-thread-per-connectionThe thread-handling model used by the server for connection threads. The permissible values are
no-threads(the server uses a single thread to handle one connection) andone-thread-per-connection(the server uses one thread to handle each client connection).no-threadsis useful for debugging under Linux; see Section 22.4, “Debugging and Porting MySQL”. This variable was added in MySQL 5.1.17 -
Command-Line Format --thread_stack=#System Variable Name thread_stackVariable Scope Global Dynamic Variable No Permitted Values (32-bit platforms) Type integerDefault 196608Min Value 131072Max Value 4294967295Block Size 1024Permitted Values (64-bit platforms) Type integerDefault 262144Min Value 131072Max Value 18446744073709547520Block Size 1024The stack size for each thread. Many of the limits detected by the
crash-metest 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. This variable is unused.
-
System Variable Name time_zoneVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type stringThe 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 ofsystem_time_zone”). The value can be specified explicitly at server startup with the--default-time-zoneoption. See Section 10.6, “MySQL Server Time Zone Support”. -
Command-Line Format --timed_mutexesSystem Variable Name timed_mutexesVariable Scope Global Dynamic Variable Yes Permitted Values Type booleanDefault OFFThis variable controls whether
InnoDBmutexes are timed. If this variable is set to 0 orOFF(the default), mutex timing is disabled. If the variable is set to 1 orON, mutex timing is enabled. With timing enabled, theos_wait_timesvalue in the output fromSHOW ENGINE INNODB MUTEXindicates the amount of time (in ms) spent in operating system waits. Otherwise, the value is 0. -
System Variable Name timestampVariable Scope Session Dynamic Variable Yes Permitted Values Type numericSet the time for this client. This is used to get the original timestamp if you use the binary log to restore rows.
timestamp_valueshould be a Unix epoch timestamp (a value like that returned byUNIX_TIMESTAMP(), not a value in'YYYY-MM-DD hh:mm:ss'format) orDEFAULT.Setting
timestampto a constant value causes it to retain that value until it is changed again. SettingtimestamptoDEFAULTcauses its value to be the current date and time as of the time it is accessed.SET timestampaffects the value returned byNOW()but not bySYSDATE(). This means that timestamp settings in the binary log have no effect on invocations ofSYSDATE(). The server can be started with the--sysdate-is-nowoption to causeSYSDATE()to be an alias forNOW(), in which caseSET timestampaffects both functions. -
Command-Line Format --tmp_table_size=#System Variable Name tmp_table_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (<= 5.1.11) Type integerDefault 33554432Min Value 1024Max Value 4294967295Permitted Values (>= 5.1.12, <= 5.1.36) Type integerDefault 16777216Min Value 1024Max Value 4294967295Permitted Values (>= 5.1.37, <= 5.1.55) Type integerDefault 16777216Min Value 1024Max Value 9223372036854775807Permitted Values (>= 5.1.56) Type integerDefault 16777216Min Value 1024Max Value 18446744073709551615The maximum size of internal in-memory temporary tables. This variable does not apply to user-created
MEMORYtables.The actual limit is determined as the minimum of
tmp_table_sizeandmax_heap_table_size. If an in-memory temporary table exceeds the limit, MySQL automatically converts it to an on-diskMyISAMtable. Increase the value oftmp_table_size(andmax_heap_table_sizeif necessary) if you do many advancedGROUP BYqueries 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_tablesandCreated_tmp_tablesvariables.See also Section 8.4.4, “Internal Temporary Table Use in MySQL”.
-
Command-Line Format --tmpdir=dir_nameSystem Variable Name tmpdirVariable Scope Global Dynamic Variable No Permitted Values Type directory nameThe 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
tmpdirto 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 orLOAD DATA INFILEoperations. If files in the temporary file directory are lost when the server restarts, replication fails. You can set the slave's temporary directory using theslave_load_tmpdirvariable. In that case, the slave will not use the generaltmpdirvalue and you can settmpdirto a nonpermanent location. -
Command-Line Format --transaction_alloc_block_size=#System Variable Name transaction_alloc_block_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 8192Min Value 1024Max Value 4294967295Block Size 1024Permitted Values (64-bit platforms) Type integerDefault 8192Min Value 1024Max Value 18446744073709547520Block Size 1024The amount in bytes by which to increase a per-transaction memory pool which needs memory. See the description of
transaction_prealloc_size. -
Command-Line Format --transaction_prealloc_size=#System Variable Name transaction_prealloc_sizeVariable Scope Global, Session Dynamic Variable Yes Permitted Values (32-bit platforms) Type integerDefault 4096Min Value 1024Max Value 4294967295Block Size 1024Permitted Values (64-bit platforms) Type integerDefault 4096Min Value 1024Max Value 18446744073709547520Block Size 1024There 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 bytransaction_alloc_block_sizebytes. When the transaction ends, the pool is truncated totransaction_prealloc_sizebytes.By making
transaction_prealloc_sizesufficiently large to contain all statements within a single transaction, you can avoid manymalloc()calls. -
System Variable Name tx_isolationVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type enumerationDefault REPEATABLE-READValid Values READ-UNCOMMITTEDREAD-COMMITTEDREPEATABLE-READSERIALIZABLEThe default transaction isolation level. Defaults to
REPEATABLE-READ.This variable can be set directly, or indirectly using the
SET TRANSACTIONstatement. See Section 13.3.6, “SET TRANSACTION Syntax”. If you settx_isolationdirectly 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-isolationserver option. -
System Variable Name unique_checksVariable Scope Session Dynamic Variable Yes Permitted Values Type booleanDefault 1If set to 1 (the default), uniqueness checks for secondary indexes in
InnoDBtables 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 toInnoDB.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.
-
Command-Line Format --updatable_views_with_limit=#System Variable Name updatable_views_with_limitVariable Scope Global, Session Dynamic Variable Yes Permitted Values Type booleanDefault 1This 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
LIMITclause. (Such updates often are generated by GUI tools.) An update is anUPDATEorDELETEstatement. Primary key here means aPRIMARY KEY, or aUNIQUEindex in which no column can containNULL.The variable can have two values:
1orYES: Issue a warning only (not an error message). This is the default value.0orNO: Prohibit the update.
The version number for the server. The value might also include a suffix indicating server build or configuration information.
-logindicates that one or more of the general log, slow query log, or binary log are enabled.-debugindicates that the server was built with debugging support enabled.-
System Variable Name version_commentVariable Scope Global Dynamic Variable No Permitted Values Type stringThe configure script has a
--with-commentoption that permits a comment to be specified when building MySQL. This variable contains the value of that comment. -
System Variable Name version_compile_machineVariable Scope Global Dynamic Variable No Permitted Values Type stringThe type of machine or architecture on which MySQL was built.
-
System Variable Name version_compile_osVariable Scope Global Dynamic Variable No Permitted Values Type stringThe type of operating system on which MySQL was built.
-
Command-Line Format --wait_timeout=#System Variable Name wait_timeoutVariable Scope Global, Session Dynamic Variable Yes Permitted Values (Windows) Type integerDefault 28800Min Value 1Max Value 2147483Permitted Values (Other) Type integerDefault 28800Min Value 1Max Value 31536000The number of seconds the server waits for activity on a noninteractive connection before closing it. Before MySQL 5.1.41, this timeout applies only to TCP/IP connections, not to connections made through Unix socket files, named pipes, or shared memory.
On thread startup, the session
wait_timeoutvalue is initialized from the globalwait_timeoutvalue or from the globalinteractive_timeoutvalue, depending on the type of client (as defined by theCLIENT_INTERACTIVEconnect option tomysql_real_connect()). See alsointeractive_timeout. 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.42, “SHOW WARNINGS Syntax”.
[mysqld]
ft_min_word_len=3
you should also set
[myisamchk]
ft_min_word_len=3
if you use myisamchk
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
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
http://www.geeksww.com/tutorials/database_management_systems/mysql/configuration/mysql_open_files_limit_openfileslimit_vs_openfileslimit_on_linux.php
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.
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