The MySQL server maintains many system variables that affect its
operation. Most 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 at runtime using the
SET
statement, which enables you to modify operation of the server
without having to stop and restart it. Some variables are
read-only, and their values are determined by the system
environment, by how MySQL is installed on the system, or possibly
by the options used to compile MySQL. Most system variables have a
default value, but there are exceptions, including read-only
variables. You can also use system variable values in expressions.
Setting a global system variable runtime value normally requires
the SYSTEM_VARIABLES_ADMIN
privilege (or the deprecated SUPER
privilege). Setting a session system runtime variable value
normally requires no special privileges and can be done by any
user, although there are exceptions. For more information, see
Section 7.1.9.1, “System Variable Privileges”
There are several ways to see the names and values of system variables:
To see the values that a server uses based on its compiled-in defaults and any option files that it reads, use this command:
mysqld --verbose --helpTo see the values that a server uses based only on its compiled-in defaults, ignoring the settings in any option files, use this command:
mysqld --no-defaults --verbose --helpTo see the current values used by a running server, use the
SHOW VARIABLESstatement or the Performance Schema system variable tables. See Section 29.12.14, “Performance Schema System Variable Tables”.
This section provides a description of each system variable. For a system variable summary table, see Section 7.1.5, “Server System Variable Reference”. For more information about manipulation of system variables, see Section 7.1.9, “Using System Variables”.
For additional system variable information, see these sections:
Section 7.1.9, “Using System Variables”, discusses the syntax for setting and displaying system variable values.
Section 7.1.9.2, “Dynamic System Variables”, lists the variables that can be set at runtime.
Information on tuning system variables can be found in Section 7.1.1, “Configuring the Server”.
Section 17.14, “InnoDB Startup Options and System Variables”, lists
InnoDBsystem variables.Section 25.4.3.9.2, “NDB Cluster System Variables”, lists system variables which are specific to NDB Cluster.
For information on server system variables specific to replication, see Section 19.1.6, “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. Boolean
variables can be set at startup to the values
ON, TRUE,
OFF, and FALSE (not
case-sensitive), as well as 1 and
0. See Section 6.2.2.4, “Program Option Modifiers”.
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 adjusts a value upward. For example, if you assign a value of 0 to a variable for which the minimal value is 1024, the server sets the value to 1024.
Values for buffer sizes, lengths, and stack sizes are given in bytes unless otherwise specified.
Some system variable descriptions include a block size, in which
case a value that is not an integer multiple of the stated block
size is rounded down to the next lower multiple of the block
size before being stored by the server, that is to
FLOOR(
value)* .
block_size
Example: Suppose that the block size for a given variable is given as 4096, and you set the value of the variable to 100000 (we assume that the variable's maximum value is greater than this number). Since 100000 / 4096 = 24.4140625, the server automatically lowers the value to 98304 (24 * 4096) before storing it.
In some cases, the stated maximum for a variable is the maximum allowed by the MySQL parser, but is not an exact multiple of the block size. In such cases, the effective maximum is the next lower multiple of the block size.
Example: A system variable's maxmum value is shown as 4294967295 (232-1), and its block size is 1024. 4294967295 / 1024 = 4194303.9990234375, so if you set this variable to its stated maximum, the value actually stored is 4194303 * 1024 = 4294966272.
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 is located under
/var/mysql/data. If the value is an absolute
path name, its location is as given by the path name.
-
Command-Line Format --activate-all-roles-on-login[={OFF|ON}]System Variable activate_all_roles_on_loginScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFWhether to enable automatic activation of all granted roles when users log in to the server:
If
activate_all_roles_on_loginis enabled, the server activates all roles granted to each account at login time. This takes precedence over default roles specified withSET DEFAULT ROLE.If
activate_all_roles_on_loginis disabled, the server activates the default roles specified withSET DEFAULT ROLE, if any, at login time.
Granted roles include those granted explicitly to the user and those named in the
mandatory_rolessystem variable value.activate_all_roles_on_loginapplies only at login time, and at the beginning of execution for stored programs and views that execute in definer context. To change the active roles within a session, useSET ROLE. To change the active roles for a stored program, the program body should executeSET ROLE. -
Command-Line Format --admin-address=addrSystem Variable admin_addressScope Global Dynamic No SET_VARHint AppliesNo Type String The IP address on which to listen for TCP/IP connections on the administrative network interface (see Section 7.1.12.1, “Connection Interfaces”). There is no default
admin_addressvalue. If this variable is not specified at startup, the server maintains no administrative interface. The server also has abind_addresssystem variable for configuring regular (nonadministrative) client TCP/IP connections. See Section 7.1.12.1, “Connection Interfaces”.If
admin_addressis specified, its value must satisfy these requirements:The value must be a single IPv4 address, IPv6 address, or host name.
The value cannot specify a wildcard address format (
*,0.0.0.0, or::).The value may include a network namespace specifier.
An IP address can be specified as an IPv4 or IPv6 address. If the value is a host name, the server resolves the name to an IP address and binds to that address. If a host name resolves to multiple IP addresses, the server uses the first IPv4 address if there are any, or the first IPv6 address otherwise.
The server treats different types of addresses as follows:
If the address is an IPv4-mapped address, the server accepts TCP/IP connections for that address, in either IPv4 or IPv6 format. For example, if the server is bound to
::ffff:127.0.0.1, clients can connect using--host=127.0.0.1or--host=::ffff:127.0.0.1.If the address is a “regular” IPv4 or IPv6 address (such as
127.0.0.1or::1), the server accepts TCP/IP connections only for that IPv4 or IPv6 address.
These rules apply to specifying a network namespace for an address:
A network namespace can be specified for an IP address or a host name.
A network namespace cannot be specified for a wildcard IP address.
For a given address, the network namespace is optional. If given, it must be specified as a
/suffix immediately following the address.nsAn address with no
/suffix uses the host system global namespace. The global namespace is therefore the default.nsAn address with a
/suffix uses the namespace namednsns.The host system must support network namespaces and each named namespace must previously have been set up. Naming a nonexistent namespace produces an error.
For additional information about network namespaces, see Section 7.1.14, “Network Namespace Support”.
If binding to the address fails, the server produces an error and does not start.
The
admin_addresssystem variable is similar to thebind_addresssystem variable that binds the server to an address for ordinary client connections, but with these differences:bind_addresspermits multiple addresses.admin_addresspermits a single address.bind_addresspermits wildcard addresses.admin_addressdoes not.
-
Command-Line Format --admin-port=port_numSystem Variable admin_portScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 33062Minimum Value 0Maximum Value 65535The TCP/IP port number to use for connections on the administrative network interface (see Section 7.1.12.1, “Connection Interfaces”). Setting this variable to 0 causes the default value to be used.
Setting
admin_porthas no effect ifadmin_addressis not specified because in that case the server maintains no administrative network interface. -
Command-Line Format --admin-ssl-ca=file_nameSystem Variable admin_ssl_caScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe
admin_ssl_casystem variable is likessl_ca, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections. -
Command-Line Format --admin-ssl-capath=dir_nameSystem Variable admin_ssl_capathScope Global Dynamic Yes SET_VARHint AppliesNo Type Directory name Default Value NULLThe
admin_ssl_capathsystem variable is likessl_capath, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections. -
Command-Line Format --admin-ssl-cert=file_nameSystem Variable admin_ssl_certScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe
admin_ssl_certsystem variable is likessl_cert, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections. -
Command-Line Format --admin-ssl-cipher=nameSystem Variable admin_ssl_cipherScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value NULLThe
admin_ssl_ciphersystem variable is likessl_cipher, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections.The list specified by this variable may include any of the following values:
ECDHE-ECDSA-AES128-GCM-SHA256ECDHE-ECDSA-AES256-GCM-SHA384ECDHE-RSA-AES128-GCM-SHA256ECDHE-RSA-AES256-GCM-SHA384ECDHE-ECDSA-CHACHA20-POLY1305ECDHE-RSA-CHACHA20-POLY1305ECDHE-ECDSA-AES256-CCMECDHE-ECDSA-AES128-CCMDHE-RSA-AES128-GCM-SHA256DHE-RSA-AES256-GCM-SHA384DHE-RSA-AES256-CCMDHE-RSA-AES128-CCMDHE-RSA-CHACHA20-POLY1305
Trying to include any values in the cipher list that are not shown here when setting this variable raises an error (
ER_BLOCKED_CIPHER). -
Command-Line Format --admin-ssl-crl=file_nameSystem Variable admin_ssl_crlScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe
admin_ssl_crlsystem variable is likessl_crl, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections. -
Command-Line Format --admin-ssl-crlpath=dir_nameSystem Variable admin_ssl_crlpathScope Global Dynamic Yes SET_VARHint AppliesNo Type Directory name Default Value NULLThe
admin_ssl_crlpathsystem variable is likessl_crlpath, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections. -
Command-Line Format --admin-ssl-key=file_nameSystem Variable admin_ssl_keyScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe
admin_ssl_keysystem variable is likessl_key, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections. -
Command-Line Format --admin-tls-ciphersuites=ciphersuite_listSystem Variable admin_tls_ciphersuitesScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value NULLThe
admin_tls_ciphersuitessystem variable is liketls_ciphersuites, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections.The value is a list of zero or more colon-separated ciphersuite names from among those listed here:
TLS_AES_128_GCM_SHA256TLS_AES_256_GCM_SHA384TLS_CHACHA20_POLY1305_SHA256TLS_AES_128_CCM_SHA256
Trying to include any values in the cipher list that are not shown here when setting this variable raises an error (
ER_BLOCKED_CIPHER). -
Command-Line Format --admin-tls-version=protocol_listSystem Variable admin_tls_versionScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value TLSv1.2,TLSv1.3The
admin_tls_versionsystem variable is liketls_version, except that it applies to the administrative connection interface rather than the main connection interface. For information about configuring encryption support for the administrative interface, see Administrative Interface Support for Encrypted Connections.ImportantMySQL 8.4 does not support the TLSv1 and TLSv1.1 connection protocols. See Removal of Support for the TLSv1 and TLSv1.1 Protocols for more information.
MuySQL 8.4 supports the TLSv1.3 protocol, provided that the MySQL server was compiled using OpenSSL 1.1.1 or newer. The server checks the version of OpenSSL at startup, and if it is older than 1.1.1, TLSv1.3 is removed from the default value for the system variable. In that case, the default is
TLSv1.2.
-
Command-Line Format --authentication-policy=valueSystem Variable authentication_policyScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value *,,This variable is used to administer multifactor authentication (MFA) capabilities. For
CREATE USERandALTER USERstatements used to manage MySQL account definitions, it determines what authentication factor or factors may be specified, where “factor” corresponds to an authentication method or plugin associated with an account.authentication_policydetermines the following aspects of multifactor authentication:The number of authentication factors.
The plugins (or methods) permitted for each factor.
The default authentication plugin for authentication specifications that do not name a plugin explicitly.
Because
authentication_policyapplies only when accounts are created or altered, changes to its value have no effect on existing user accounts.NoteAlthough the
authentication_policysystem variable places certain constraints on the authentication-related clauses ofCREATE USERandALTER USERstatements, a user who has theAUTHENTICATION_POLICY_ADMINprivilege is not subject to these constraints. (A warning does occur for statements that otherwise would not be permitted.)The value of
authentication_policyis a list of 1, 2, or 3 comma-separated elements, each corresponding to an authentication factor and each being of one of the forms listed here, with their meanings:empty
The authentication factor is optional; any authentication plugin may be used.
*The authentication factor is required; any authentication plugin may be used.
plugin_nameThe authentication factor is required; this factor must be
plugin_name.*:plugin_nameThe authentication factor is required;
plugin_nameis the default, but another authentication plugin may be used.
In each case, an element may be surrounded by whitespace characters. The entire list must be enclosed in single quotes.
authentication_policymust contain at least one nonempty factor, and any empty factors must come at the end of the list, following any nonempty factors. This means that',,'is not permitted because this signifies that all factors are optional. Every account must have at least one authentication factor.The default value of
authentication_policyis'*,,'. This means that factor 1 is required in account definitions and can use any authentication plugin (withcaching_sha2_passwordbeing the default), and that factors 2 and 3 are optional and each can use any authentication plugin.If
authentication_policydoes not specify a default plugin for the first factor, the default plugin for this factor iscaching_sha2_password, although another plugin may be used.The following table shows some possible values for
authentication_policyand the policy that each establishes for creating or altering accounts.Table 7.4 Example authentication_policy Values
authentication_policy Policy '*'One factor only, which uses caching_sha2_password, although another plugin may be used.'*,*'Two factors only; the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second may use any plugin.'*,*,*'Three factors only, where the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second and third factors may use any plugins.'*,'One or two factors, where the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second factor is optional and may use any plugin.'*,,'One, two, or three factors, where the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second factor and third factors are optional and may use any plugins.'*,*,'Two or three factors, where the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second factor is required and the third factor is optional; the second and third factors may use any plugins.'*,auth_plugin'Two factors, where the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second factor must be the named plugin.'auth_plugin,*,'Two or three factors, where the first factor must be the named plugin; the second factor is required but may use any plugin; the third factor is optional and may use any plugin. '*,*:auth_plugin'Two factors, where the first factor uses caching_sha2_passwordby default, although another plugin may be used; the second factor is required and uses the named plugin, but another plugin may be used.'auth_plugin,'One or two factors, where the first factor must be the named plugin; the second factor is optional and may use any plugin. '*:auth_plugin,*,'Two or three factors, where the first factor must be the named plugin; the second factor is required and may use any plugin, and the third factor is optional and may use any plugin. 'auth_plugin,auth_plugin,auth_plugin'Three factors, where all three factors must use the named plugins. authentication_windows_log_levelCommand-Line Format --authentication-windows-log-level=#System Variable authentication_windows_log_levelScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 2Minimum Value 0Maximum Value 4This variable is available only if the
authentication_windowsWindows authentication plugin is enabled and debugging code is enabled. See Section 8.4.1.6, “Windows Pluggable Authentication”.This variable sets the logging level for the Windows authentication plugin. The following table shows the permitted values.
Value Description 0 No logging 1 Log only error messages 2 Log level 1 messages and warning messages 3 Log level 2 messages and information notes 4 Log level 3 messages and debug messages authentication_windows_use_principal_nameCommand-Line Format --authentication-windows-use-principal-name[={OFF|ON}]System Variable authentication_windows_use_principal_nameScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONThis variable is available only if the
authentication_windowsWindows authentication plugin is enabled. See Section 8.4.1.6, “Windows Pluggable Authentication”.A client that authenticates using the
InitSecurityContext()function should provide a string identifying the service to which it connects (targetName). MySQL uses the principal name (UPN) of the account under which the server is running. The UPN has the formand need not be registered anywhere to be used. This UPN is sent by the server at the beginning of authentication handshake.user_id@computer_nameThis variable controls whether the server sends the UPN in the initial challenge. By default, the variable is enabled. For security reasons, it can be disabled to avoid sending the server's account name to a client as cleartext. If the variable is disabled, the server always sends a
0x00byte in the first challenge, the client does not specifytargetName, and as a result, NTLM authentication is used.If the server fails to obtain its UPN (which happens primarily in environments that do not support Kerberos authentication), the UPN is not sent by the server and NTLM authentication is used.
-
Command-Line Format --autocommit[={OFF|ON}]System Variable autocommitScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value 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 15.3.1, “START TRANSACTION, COMMIT, and ROLLBACK Statements”.By default, client connections begin with
autocommitset to 1. To cause clients to begin with a default of 0, set the globalautocommitvalue by starting the server with the--autocommit=0option. To set the variable using an option file, include these lines:[mysqld] autocommit=0 -
Command-Line Format --automatic-sp-privileges[={OFF|ON}]System Variable automatic_sp_privilegesScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONWhen 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.If you start mysqld with
--skip-new,automatic_sp_privilegesis set toOFF.See also Section 27.2.2, “Stored Routines and MySQL Privileges”.
-
Command-Line Format --auto-generate-certs[={OFF|ON}]System Variable auto_generate_certsScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONThis variable controls whether the server autogenerates SSL key and certificate files in the data directory, if they do not already exist.
At startup, the server automatically generates server-side and client-side SSL certificate and key files in the data directory if the
auto_generate_certssystem variable is enabled and the server-side SSL files are missing from the data directory. These certificates are always generated in such cases, regardless of the values of any other TLS options. The certificate and key files enable secure client connections using SSL; see Section 8.3.1, “Configuring MySQL to Use Encrypted Connections”.For more information about SSL file autogeneration, including file names and characteristics, see Section 8.3.3.1, “Creating SSL and RSA Certificates and Keys using MySQL”
The
sha256_password_auto_generate_rsa_keysandcaching_sha2_password_auto_generate_rsa_keyssystem variables are related but control autogeneration of RSA key-pair files needed for secure password exchange using RSA over unencrypted connections. -
Command-Line Format --back-log=#System Variable back_logScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value -1(signifies autosizing; do not assign this literal value)Minimum Value 1Maximum 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.The default value is the value of
max_connections, which enables the permitted backlog to adjust to the maximum permitted number of connections. -
Command-Line Format --basedir=dir_nameSystem Variable basedirScope Global Dynamic No SET_VARHint AppliesNo Type Directory name Default Value parent of mysqld installation directoryThe path to the MySQL installation base directory.
-
Command-Line Format --big-tables[={OFF|ON}]System Variable big_tablesScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIf enabled, the server stores all temporary tables on disk rather than in memory. This prevents most
The tableerrors fortbl_nameis fullSELECToperations that require a large temporary table, but also slows down queries for which in-memory tables would suffice.The default value for new connections is
OFF(use in-memory temporary tables). Normally, it should never be necessary to enable this variable. When in-memory internal temporary tables are managed by theTempTablestorage engine (the default), and the maximum amount of memory that can be occupied by theTempTablestorage engine is exceeded, theTempTablestorage engine starts storing data to temporary files on disk. When in-memory temporary tables are managed by theMEMORYstorage engine, in-memory tables are automatically converted to disk-based tables as required. For more information, see Section 10.4.4, “Internal Temporary Table Use in MySQL”. -
Command-Line Format --bind-address=addrSystem Variable bind_addressScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value *The MySQL server listens on one or more network sockets for TCP/IP connections. Each socket is bound to one address, but it is possible for an address to map onto multiple network interfaces. To specify how the server should listen for TCP/IP connections, set the
bind_addresssystem variable at server startup. The server also has anadmin_addresssystem variable that enables administrative connections on a dedicated interface. See Section 7.1.12.1, “Connection Interfaces”.If
bind_addressis specified, it accepts a list of one or more address values, each of which may specify a single non-wildcard IP address or host name. Each address may include a network namespace specifier. If only one address is specified, it may make use of one of the wildcard address formats that permit listening on multiple network interfaces (*,0.0.0.0, or::). Multiple addresses are separated by commas. When multiple values are listed, each value must specify a single non-wildcard IP address (either IPv4 or IPv6) or a host name, and wildcard address formats (*,0.0.0.0, or::) are not allowed.IP addresses can be specified as IPv4 or IPv6 addresses. For any value that is a host name, the server resolves the name to an IP address and binds to that address. If a host name resolves to multiple IP addresses, the server uses the first IPv4 address if there are any, or the first IPv6 address otherwise.
The server treats different types of addresses as follows:
If the address is
*, the server accepts TCP/IP connections on all server host IPv4 interfaces, and, if the server host supports IPv6, on all IPv6 interfaces. Use this address to permit both IPv4 and IPv6 connections on all server interfaces. This value is the default. If the variable specifies a list of multiple values, this value is not permitted.If the address is
0.0.0.0, the server accepts TCP/IP connections on all server host IPv4 interfaces. If the variable specifies a list of multiple values, this value is not permitted.If the address is
::, the server accepts TCP/IP connections on all server host IPv4 and IPv6 interfaces. If the variable specifies a list of multiple values, this value is not permitted.If the address is an IPv4-mapped address, the server accepts TCP/IP connections for that address, in either IPv4 or IPv6 format. For example, if the server is bound to
::ffff:127.0.0.1, clients can connect using--host=127.0.0.1or--host=::ffff:127.0.0.1.If the address is a “regular” IPv4 or IPv6 address (such as
127.0.0.1or::1), the server accepts TCP/IP connections only for that IPv4 or IPv6 address.
These rules apply to specifying a network namespace for an address:
A network namespace can be specified for an IP address or a host name.
A network namespace cannot be specified for a wildcard IP address.
For a given address, the network namespace is optional. If given, it must be specified as a
/suffix immediately following the address.nsAn address with no
/suffix uses the host system global namespace. The global namespace is therefore the default.nsAn address with a
/suffix uses the namespace namednsns.The host system must support network namespaces and each named namespace must previously have been set up. Naming a nonexistent namespace produces an error.
If the variable value specifies multiple addresses, it can include addresses in the global namespace, in named namespaces, or a mix.
For additional information about network namespaces, see Section 7.1.14, “Network Namespace Support”.
If binding to any address fails, the server produces an error and does not start.
Examples:
bind_address=*The server listens on all IPv4 or IPv6 addresses, as specified by the
*wildcard.bind_address=198.51.100.20The server listens only on the
198.51.100.20IPv4 address.bind_address=198.51.100.20,2001:db8:0:f101::1The server listens on the
198.51.100.20IPv4 address and the2001:db8:0:f101::1IPv6 address.bind_address=198.51.100.20,*This produces an error because wildcard addresses are not permitted when
bind_addressnames a list of multiple values.bind_address=198.51.100.20/red,2001:db8:0:f101::1/blue,192.0.2.50The server listens on the
198.51.100.20IPv4 address in therednamespace, the2001:db8:0:f101::1IPv6 address in thebluenamespace, and the192.0.2.50IPv4 address in the global namespace.
When
bind_addressnames a single value (wildcard or non-wildcard), the server listens on a single socket, which for a wildcard address may be bound to multiple network interfaces. Whenbind_addressnames a list of multiple values, the server listens on one socket per value, with each socket bound to a single network interface. The number of sockets is linear with the number of values specified. Depending on operating system connection-acceptance efficiency, long value lists might incur a performance penalty for accepting TCP/IP connections.Because file descriptors are allocated for listening sockets and network namespace files, it may be necessary to increase the
open_files_limitsystem variable.If you intend to bind the server to a specific address, be sure that the
mysql.usersystem table contains an account with administrative privileges that you can use to connect to that address. Otherwise, you cannot shut down the server. For example, if you bind the server to*, you can connect to it using all existing accounts. But if you bind the server to::1, it accepts connections only on that address. In that case, first make sure that the'root'@'::1'account is present in themysql.usertable so you can still connect to the server to shut it down. -
Command-Line Format --block-encryption-mode=#System Variable block_encryption_modeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value aes-128-ecbThis variable controls the block encryption mode for block-based algorithms such as AES. It affects encryption for
AES_ENCRYPT()andAES_DECRYPT().block_encryption_modetakes a value inaes-format, wherekeylen-modekeylenis the key length in bits andmodeis the encryption mode. The value is not case-sensitive. Permittedkeylenvalues are 128, 192, and 256. Permittedmodevalues areECB,CBC,CFB1,CFB8,CFB128, andOFB.For example, this statement causes the AES encryption functions to use a key length of 256 bits and the CBC mode:
SET block_encryption_mode = 'aes-256-cbc';An error occurs for attempts to set
block_encryption_modeto a value containing an unsupported key length or a mode that the SSL library does not support. -
This is a 160-bit
SHA1signature which is generated by the linker when compiling the server on Linux systems with-DWITH_BUILD_ID=ON(enabled by default), and converted to a hexadecimal string. This read-only value serves as a unique build ID, and is written into the server log at startup.build_idis not supported on platforms other than Linux. -
Command-Line Format --bulk-insert-buffer-size=#System Variable bulk_insert_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 8388608Minimum Value 0Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295Unit bytes/thread MyISAMuses a special tree-like cache to make bulk inserts faster forINSERT ... SELECT,INSERT ... VALUES (...), (...), ..., andLOAD DATAwhen 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.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
caching_sha2_password_digest_roundsCommand-Line Format --caching-sha2-password-digest-rounds=#System Variable caching_sha2_password_digest_roundsScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 5000Minimum Value 5000Maximum Value 4095000The number of hash rounds used by the
caching_sha2_passwordauthentication plugin for password storage.Increasing the number of hashing rounds above the default value incurs a performance penalty that correlates with the amount of increase:
Creating an account that uses the
caching_sha2_passwordplugin has no impact on the client session within which the account is created, but the server must perform the hashing rounds to complete the operation.For client connections that use the account, the server must perform the hashing rounds and save the result in the cache. The result is longer login time for the first client connection, but not for subsequent connections. This behavior occurs after each server restart.
caching_sha2_password_auto_generate_rsa_keysCommand-Line Format --caching-sha2-password-auto-generate-rsa-keys[={OFF|ON}]System Variable caching_sha2_password_auto_generate_rsa_keysScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONThe server uses this variable to determine whether to autogenerate RSA private/public key-pair files in the data directory if they do not already exist.
At startup, the server automatically generates RSA private/public key-pair files in the data directory if all of these conditions are true: The
sha256_password_auto_generate_rsa_keysorcaching_sha2_password_auto_generate_rsa_keyssystem variable is enabled; no RSA options are specified; the RSA files are missing from the data directory. These key-pair files enable secure password exchange using RSA over unencrypted connections for accounts authenticated by thesha256_password(deprecated) orcaching_sha2_passwordplugin; see Section 8.4.1.3, “SHA-256 Pluggable Authentication”, and Section 8.4.1.2, “Caching SHA-2 Pluggable Authentication”.For more information about RSA file autogeneration, including file names and characteristics, see Section 8.3.3.1, “Creating SSL and RSA Certificates and Keys using MySQL”
The
auto_generate_certssystem variable is related but controls autogeneration of SSL certificate and key files needed for secure connections using SSL.caching_sha2_password_private_key_pathCommand-Line Format --caching-sha2-password-private-key-path=file_nameSystem Variable caching_sha2_password_private_key_pathScope Global Dynamic No SET_VARHint AppliesNo Type File name Default Value private_key.pemThis variable specifies the path name of the RSA private key file for the
caching_sha2_passwordauthentication plugin. If the file is named as a relative path, it is interpreted relative to the server data directory. The file must be in PEM format.ImportantBecause this file stores a private key, its access mode should be restricted so that only the MySQL server can read it.
For information about
caching_sha2_password, see Section 8.4.1.2, “Caching SHA-2 Pluggable Authentication”.caching_sha2_password_public_key_pathCommand-Line Format --caching-sha2-password-public-key-path=file_nameSystem Variable caching_sha2_password_public_key_pathScope Global Dynamic No SET_VARHint AppliesNo Type File name Default Value public_key.pemThis variable specifies the path name of the RSA public key file for the
caching_sha2_passwordauthentication plugin. If the file is named as a relative path, it is interpreted relative to the server data directory. The file must be in PEM format.For information about
caching_sha2_password, including information about how clients request the RSA public key, see Section 8.4.1.2, “Caching SHA-2 Pluggable Authentication”.-
System Variable character_set_clientScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4The 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 12.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. This can happen when the client requests a character set not known to the server, such as when a Japanese-enabled client requestssjiswhen connecting to a server not configured withsjissupport.Some character sets cannot be used as the client character set. Attempting to use them as the
character_set_clientvalue produces an error. See Impermissible Client Character Sets. -
System Variable character_set_connectionScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4The character set used for literals specified without a character set introducer and for number-to-string conversion. For information about introducers, see Section 12.3.8, “Character Set Introducers”.
-
System Variable character_set_databaseScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4Footnote This option is dynamic, but should be set only by server. You should not set this variable manually. The character set used by the default database. The server sets this variable whenever the default database changes. If there is no default database, the variable has the same value as
character_set_server.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
The global
character_set_databaseandcollation_databasesystem variables are deprecated; expect them to be removed in a future version of MySQL.Assigning a value to the session
character_set_databaseandcollation_databasesystem variables is deprecated and assignments produce a warning. Expect the session variables to become read-only (and assignments to them to produce an error) in a future version of MySQL in which it remains possible to access the session variables to determine the database character set and collation for the default database. -
Command-Line Format --character-set-filesystem=nameSystem Variable character_set_filesystemScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value binaryThe file system character set. This variable is used to interpret string literals that refer to file names, such as in the
LOAD DATAandSELECT ... 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'utf8mb4'.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
System Variable character_set_resultsScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4The character set used for returning query results to the client. This includes result data such as column values, result metadata such as column names, and error messages.
-
Command-Line Format --character-set-server=nameSystem Variable character_set_serverScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4The servers default character set. See Section 12.15, “Character Set Configuration”. If you set this variable, you should also set
collation_serverto specify the collation for the character set. -
System Variable character_set_systemScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value utf8mb3The character set used by the server for storing identifiers. The value is always
utf8mb3. -
Command-Line Format --character-sets-dir=dir_nameSystem Variable character_sets_dirScope Global Dynamic No SET_VARHint AppliesNo Type Directory name The directory where character sets are installed. See Section 12.15, “Character Set Configuration”.
-
Command-Line Format --check-proxy-users[={OFF|ON}]System Variable check_proxy_usersScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFSome authentication plugins implement proxy user mapping for themselves (for example, the PAM and Windows authentication plugins). Other authentication plugins do not support proxy users by default. Of these, some can request that the MySQL server itself map proxy users according to granted proxy privileges:
mysql_native_password(deprecated),sha256_password(deprecated).If the
check_proxy_userssystem variable is enabled, the server performs proxy user mapping for any authentication plugins that make such a request. It may also be necessary to enable plugin-specific system variables to take advantage of server proxy user mapping support:For the deprecated
mysql_native_passwordplugin (deprecated), enablemysql_native_password_proxy_users.For the
sha256_passwordplugin (deprecated), enablesha256_password_proxy_users.
For information about user proxying, see Section 8.2.19, “Proxy Users”.
-
System Variable collation_connectionScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String The collation of the connection character set.
collation_connectionis important for comparisons of literal strings. For comparisons of strings with column values,collation_connectiondoes not matter because columns have their own collation, which has a higher collation precedence (see Section 12.8.4, “Collation Coercibility in Expressions”).Using the name of a user-defined collation for this variable raises a warning.
-
System Variable collation_databaseScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4_0900_ai_ciFootnote This option is dynamic, but should be set only by server. You should not set this variable manually. The collation used by the default database. The server sets this variable whenever the default database changes. If there is no default database, the variable has the same value as
collation_server.The global
character_set_databaseandcollation_databasesystem variables are deprecated; expect them to be removed in a future version of MySQL.Assigning a value to the session
character_set_databaseandcollation_databasesystem variables is deprecated and assignments produce a warning. Expect the session variables to become read-only (and assignments to produce an error) in a future version of MySQL in which it remains possible to access the session variables to determine the database character set and collation for the default database.Using the name of a user-defined collation for
collation_databaseraises a warning. -
Command-Line Format --collation-server=nameSystem Variable collation_serverScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value utf8mb4_0900_ai_ciThe server's default collation. See Section 12.15, “Character Set Configuration”.
Setting this to the name of a user-defined collation raises a warning.
-
Command-Line Format --completion-type=#System Variable completion_typeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value NO_CHAINValid Values NO_CHAINCHAINRELEASE012The transaction completion type. This variable can take the values shown in the following table. The variable can be assigned using either the name values or corresponding integer values.
Value Description NO_CHAIN(or 0)COMMITandROLLBACKare unaffected. This is the default value.CHAIN(or 1)COMMITandROLLBACKare equivalent toCOMMIT AND CHAINandROLLBACK AND CHAIN, respectively. (A new transaction starts immediately with the same isolation level as the just-terminated transaction.)RELEASE(or 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 15.3.3, “Statements That Cause an Implicit Commit”. It also does not apply forXA COMMIT,XA ROLLBACK, or whenautocommit=1. -
Command-Line Format --component-scheduler.enabled[=value]System Variable component_scheduler.enabledScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONWhen set to
OFFat startup, the background thread does not start. Tasks can still be scheduled, but they do not run untilcomponent_scheduleris enabled. When set toONat startup, the component is fully operational.It is also possible to set the value dynamically to get the following effects:
ONstarts the background thread that begins servicing the queue immediately.OFFsignals a termination of the background thread, which waits for it to end. The background thread checks the termination flag before accessing the queue to check for tasks to execute.
-
Command-Line Format --concurrent-insert[=value]System Variable concurrent_insertScope Global Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value AUTOValid Values NEVERAUTOALWAYS012If
AUTO(the default), MySQL permitsINSERTandSELECTstatements to run concurrently forMyISAMtables that have no free blocks in the middle of the data file.This variable can take the values shown in the following table. The variable can be assigned using either the name values or corresponding integer values.
Value Description NEVER(or 0)Disables concurrent inserts AUTO(or 1)(Default) Enables concurrent insert for MyISAMtables that do not have holesALWAYS(or 2)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.If you start mysqld with
--skip-new,concurrent_insertis set toNEVER.See also Section 10.11.3, “Concurrent Inserts”.
-
Command-Line Format --connect-timeout=#System Variable connect_timeoutScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 10Minimum Value 2Maximum Value 31536000Unit seconds The number of seconds that the mysqld server waits for a connect packet before responding with
Bad handshake. The default value is 10 seconds.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 --connection-memory-chunk-size=#System Variable connection_memory_chunk_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8192Minimum Value 0Maximum Value 536870912Unit bytes Set the chunking size for updates to the global memory usage counter
Global_connection_memory. The status variable is updated only when total memory consumption by all user connections changes by more than this amount. Disable updates by settingconnection_memory_chunk_size = 0.The memory calculation is exclusive of any memory used by system users such as the MySQL root user. Memory used by the
InnoDBbuffer pool is also not included.You must have the
SYSTEM_VARIABLES_ADMINorSUPERprivilege to set this variable. -
Command-Line Format --connection-memory-limit=#System Variable connection_memory_limitScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 18446744073709551615Minimum Value 2097152Maximum Value 18446744073709551615Unit bytes Set the maximum amount of memory that can be used by a single user connection. If any user connection uses more than this amount, all queries from this connection are rejected with
ER_CONN_LIMIT, including any queries currently running.The limit set by this variable does not apply to system users, or to the MySQL root account. Memory used by the
InnoDBbuffer pool is also not included.You must have the
SYSTEM_VARIABLES_ADMINorSUPERprivilege to set this variable. -
System Variable core_fileScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFWhether to write a core file if the server unexpectedly exits. This variable is set by the
--core-fileoption. -
Command-Line Format --create-admin-listener-thread[={OFF|ON}]System Variable create_admin_listener_threadScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFWhether to use a dedicated listening thread for client connections on the administrative network interface (see Section 7.1.12.1, “Connection Interfaces”). The default is
OFF; that is, the manager thread for ordinary connections on the main interface also handles connections for the administrative interface.Depending on factors such as platform type and workload, you may find one setting for this variable yields better performance than the other setting.
Setting
create_admin_listener_threadhas no effect ifadmin_addressis not specified because in that case the server maintains no administrative network interface. -
Command-Line Format --cte-max-recursion-depth=#System Variable cte_max_recursion_depthScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1000Minimum Value 0Maximum Value 4294967295The common table expression (CTE) maximum recursion depth. The server terminates execution of any CTE that recurses more levels than the value of this variable. For more information, see Limiting Common Table Expression Recursion.
-
Command-Line Format --datadir=dir_nameSystem Variable datadirScope Global Dynamic No SET_VARHint AppliesNo Type Directory name The path to the MySQL server data directory. Relative paths are resolved with respect to the current directory. If you expect the server to be started automatically (that is, in contexts for which you cannot know the current directory in advance), it is best to specify the
datadirvalue as an absolute path. -
Command-Line Format --debug[=debug_options]System Variable debugScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value (Unix) d:t:i:o,/tmp/mysqld.traceDefault Value (Windows) 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.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
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 | +---------+For more information, see Section 7.9.4, “The DBUG Package”.
-
System Variable debug_syncScope Session Dynamic Yes SET_VARHint AppliesNo Type String This variable is the user interface to the Debug Sync facility. Use of Debug Sync requires that MySQL be configured with the
-DWITH_DEBUG=ONCMake option (see Section 2.8.7, “MySQL Source-Configuration Options”); otherwise, 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 has the same value as the global variable. The session value can be set to control synchronization points.
Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
For a description of the Debug Sync facility and how to use synchronization points, see MySQL Internals: Test Synchronization.
-
System Variable default_collation_for_utf8mb4Scope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value utf8mb4_0900_ai_ciValid Values utf8mb4_0900_ai_ciutf8mb4_general_ciImportantThe
default_collation_for_utf8mb4system variable is for internal use by MySQL Replication only.This variable is set by the server to the default collation for the
utf8mb4character set. The value of the variable is replicated from a source to a replica so that the replica can correctly process data originating from a source with a different default collation forutf8mb4. This variable is primarily intended to support replication from a MySQL 5.7 or older replication source server to a later MySQL replica server, or group replication with a MySQL 5.7 primary node and one or more MySQL 8.0 or later secondaries. The default collation forutf8mb4in MySQL 5.7 isutf8mb4_general_ci, bututf8mb4_0900_ai_ciin later release series. The variable is not present in releases earlier than MySQL 8.0, so if the replica does not receive a value for the variable, it assumes the source is from an earlier release and sets the value to the previous default collationutf8mb4_general_ci.The default
utf8mb4collation is used in the following statements:CREATE TABLEandALTER TABLEhaving aCHARACTER SET utf8mb4clause without aCOLLATIONclause, either for the table character set or for a column character set.CREATE DATABASEandALTER DATABASEhaving aCHARACTER SET utf8mb4clause without aCOLLATIONclause.Any statement containing a string literal of the form
_utf8mb4'without asome text'COLLATEclause.
See also Section 12.9, “Unicode Support”.
-
Command-Line Format --default-password-lifetime=#System Variable default_password_lifetimeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 65535Unit days This variable defines the global automatic password expiration policy. The default
default_password_lifetimevalue is 0, which disables automatic password expiration. If the value ofdefault_password_lifetimeis a positive integerN, it indicates the permitted password lifetime; passwords must be changed everyNdays.The global password expiration policy can be overridden as desired for individual accounts using the password expiration option of the
CREATE USERandALTER USERstatements. See Section 8.2.15, “Password Management”. -
Command-Line Format --default-storage-engine=nameSystem Variable default_storage_engineScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value InnoDBThe default storage engine for tables. See Chapter 18, Alternative Storage Engines. This variable sets the storage engine for permanent tables only. To set the storage engine for
TEMPORARYtables, set thedefault_tmp_storage_enginesystem variable.To see which storage engines are available and enabled, use the
SHOW ENGINESstatement or query theINFORMATION_SCHEMAENGINEStable.If you disable the default storage engine at server startup, you must set the default engine for both permanent and
TEMPORARYtables to a different engine, or else the server does not start. -
Command-Line Format --default-table-encryption[={OFF|ON}]System Variable default_table_encryptionScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFDefines the default encryption setting applied to schemas and general tablespaces when they are created without specifying an
ENCRYPTIONclause.The
default_table_encryptionvariable is only applicable to user-created schemas and general tablespaces. It does not govern encryption of themysqlsystem tablespace.Setting the runtime value of
default_table_encryptionrequires theSYSTEM_VARIABLES_ADMINandTABLE_ENCRYPTION_ADMINprivileges, or the deprecatedSUPERprivilege.The value of
default_table_encryptioncannot be changed while Group Replication is running.default_table_encryptionsupportsSET PERSISTandSET PERSIST_ONLYsyntax. See Section 7.1.9.3, “Persisted System Variables”.For more information, see Defining an Encryption Default for Schemas and General Tablespaces.
-
Command-Line Format --default-tmp-storage-engine=nameSystem Variable default_tmp_storage_engineScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Enumeration Default Value InnoDBThe default storage engine for
TEMPORARYtables (created withCREATE TEMPORARY TABLE). To set the storage engine for permanent tables, set thedefault_storage_enginesystem variable. Also see the discussion of that variable regarding possible values.If you disable the default storage engine at server startup, you must set the default engine for both permanent and
TEMPORARYtables to a different engine, or else the server does not start. -
Command-Line Format --default-week-format=#System Variable default_week_formatScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 7The default mode value to use for the
WEEK()function. See Section 14.7, “Date and Time Functions”. -
Command-Line Format --delay-key-write[={OFF|ON|ALL}]System Variable delay_key_writeScope Global Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value ONValid Values OFFONALLThis variable specifies how to use delayed key writes. It applies only to
MyISAMtables. Delayed key writing causes key buffers not to be flushed between writes. See also Section 18.2.1, “MyISAM Startup Options”.This variable can have one of the following values to affect handling of the
DELAY_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.NoteIf you set this variable to
ALL, you should not useMyISAMtables from within another program (such as another MySQL server or myisamchk) when the tables are in use. Doing so leads to index corruption.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 themyisam_recover_optionssystem variable set (for example,myisam_recover_options='BACKUP,FORCE'). See Section 7.1.8, “Server System Variables”, and Section 18.2.1, “MyISAM Startup Options”.If you start mysqld with
--skip-new,delay_key_writeis set toOFF.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=#Deprecated Yes System Variable delayed_insert_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 100Minimum Value 1Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295This system variable is deprecated (because
DELAYEDinserts are not supported), and you should expect it to be removed in a future release. -
Command-Line Format --delayed-insert-timeout=#Deprecated Yes System Variable delayed_insert_timeoutScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 300Minimum Value 1Maximum Value 31536000Unit seconds This system variable is deprecated (because
DELAYEDinserts are not supported), and you should expect it to be removed in a future release. -
Command-Line Format --delayed-queue-size=#Deprecated Yes System Variable delayed_queue_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1000Minimum Value 1Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295This system variable is deprecated (because
DELAYEDinserts are not supported), and you should expect it to be removed in a future release. -
Command-Line Format --disabled-storage-engines=engine[,engine]...System Variable disabled_storage_enginesScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value empty stringThis variable indicates which storage engines cannot be used to create tables or tablespaces. For example, to prevent new
MyISAMorFEDERATEDtables from being created, start the server with these lines in the server option file:[mysqld] disabled_storage_engines="MyISAM,FEDERATED"By default,
disabled_storage_enginesis empty (no engines disabled), but it can be set to a comma-separated list of one or more engines (not case-sensitive). Any engine named in the value cannot be used to create tables or tablespaces withCREATE TABLEorCREATE TABLESPACE, and cannot be used withALTER TABLE ... ENGINEorALTER TABLESPACE ... ENGINEto change the storage engine of existing tables or tablespaces. Attempts to do so result in anER_DISABLED_STORAGE_ENGINEerror.disabled_storage_enginesdoes not restrict other DDL statements for existing tables, such asCREATE INDEX,TRUNCATE TABLE,ANALYZE TABLE,DROP TABLE, orDROP TABLESPACE. This permits a smooth transition so that existing tables or tablespaces that use a disabled engine can be migrated to a permitted engine by means such asALTER TABLE ... ENGINE.permitted_engineIt is permitted to set the
default_storage_engineordefault_tmp_storage_enginesystem variable to a storage engine that is disabled. This could cause applications to behave erratically or fail, although that might be a useful technique in a development environment for identifying applications that use disabled engines, so that they can be modified.disabled_storage_enginesis disabled and has no effect if the server is started with any of these options:--initialize,--initialize-insecure,--skip-grant-tables. disconnect_on_expired_passwordCommand-Line Format --disconnect-on-expired-password[={OFF|ON}]System Variable disconnect_on_expired_passwordScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONThis variable controls how the server handles clients with expired passwords:
If the client indicates that it can handle expired passwords, the value of
disconnect_on_expired_passwordis irrelevant. The server permits the client to connect but puts it in sandbox mode.If the client does not indicate that it can handle expired passwords, the server handles the client according to the value of
disconnect_on_expired_password:If
disconnect_on_expired_password: is enabled, the server disconnects the client.If
disconnect_on_expired_password: is disabled, the server permits the client to connect but puts it in sandbox mode.
For more information about the interaction of client and server settings relating to expired-password handling, see Section 8.2.16, “Server Handling of Expired Passwords”.
-
Command-Line Format --div-precision-increment=#System Variable div_precision_incrementScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 4Minimum Value 0Maximum 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 | +----------------+ dragnet.log_error_filter_rulesCommand-Line Format --dragnet.log-error-filter-rules=valueSystem Variable dragnet.log_error_filter_rulesScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value IF prio>=INFORMATION THEN drop. IF EXISTS source_line THEN unset source_line.The filter rules that control operation of the
log_filter_dragneterror log filter component. Iflog_filter_dragnetis not installed,dragnet.log_error_filter_rulesis unavailable. Iflog_filter_dragnetis installed but not enabled, changes todragnet.log_error_filter_ruleshave no effect.The effect of the default value is similar to the filtering performed by the
log_sink_internalfilter with a setting oflog_error_verbosity=2.dragnet.Statusstatus variable can be consulted to determine the result of the most recent assignment todragnet.log_error_filter_rules.enterprise_encryption.maximum_rsa_key_sizeCommand-Line Format --enterprise-encryption.maximum-rsa-key-size=#System Variable enterprise_encryption.maximum_rsa_key_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 4096Minimum Value 2048Maximum Value 16384This variable limits the maximum size of RSA keys generated by MySQL Enterprise Encryption. The variable is available only if the MySQL Enterprise Encryption component
component_enterprise_encryptionis installed.The lowest setting is 2048 bits, which is the minimum RSA key length that is acceptable by current best practice. The default setting is 4096 bits. The highest setting is 16384 bits. Generating longer keys can consume significant CPU resources, so you can use this setting to limit keys to a length that provides adequate security for your requirements while balancing this with resource usage. See Section 8.6.2, “Configuring MySQL Enterprise Encryption” for more information.
enterprise_encryption.rsa_support_legacy_paddingCommand-Line Format --enterprise-encryption.rsa_support_legacy_padding[={OFF|ON}]System Variable enterprise_encryption.rsa_support_legacy_paddingScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable controls whether encrypted data and signatures that MySQL Enterprise Encryption produced using the old
openssl_udfshared library functions can be decrypted or verified by the MySQL Enterprise Encryption component (component_enterprise_encryption). The variable is available only if the MySQL Enterprise Encryption component is installed.For the component functions to support decryption and verification for content produced by the old
openssl_udfshared library functions, you must set the system variable padding toON. WhenONis set, if the component functions cannot decrypt or verify content when assuming it has the RSAES-OAEP or RSASSA-PSS scheme (as used by the component), they make another attempt assuming it has the RSAES-PKCS1-v1_5 or RSASSA-PKCS1-v1_5 scheme (as used by theopenssl_udfshared library functions). WhenOFFis set, if the component functions cannot decrypt or verify content using their normal schemes, they return null output. See Section 8.6.2, “Configuring MySQL Enterprise Encryption” for more information.-
Command-Line Format --end-markers-in-json[={OFF|ON}]System Variable end_markers_in_jsonScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFWhether optimizer JSON output should add end markers. See Section 10.15.9, “The end_markers_in_json System Variable”.
-
Command-Line Format --eq-range-index-dive-limit=#System Variable eq_range_index_dive_limitScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 200Minimum Value 0Maximum Value 4294967295This variable indicates the number of equality ranges in an equality comparison condition when the optimizer should switch from using index dives to index statistics in estimating the number of qualifying rows. It applies to evaluation of expressions that have either of these equivalent forms, where the optimizer uses a nonunique index to look up
col_namevalues:col_name IN(val1, ..., valN) col_name = val1 OR ... OR col_name = valNIn both cases, the expression contains
Nequality ranges. The optimizer can make row estimates using index dives or index statistics. Ifeq_range_index_dive_limitis greater than 0, the optimizer uses existing index statistics instead of index dives if there areeq_range_index_dive_limitor more equality ranges. Thus, to permit use of index dives for up toNequality ranges, seteq_range_index_dive_limittoN+ 1. To disable use of index statistics and always use index dives regardless ofN, seteq_range_index_dive_limitto 0.For more information, see Equality Range Optimization of Many-Valued Comparisons.
To update table index statistics for best estimates, use
ANALYZE TABLE. The number of errors that resulted from the last statement that generated messages. This variable is read only. See Section 15.7.7.18, “SHOW ERRORS Statement”.
-
Command-Line Format --event-scheduler[=value]System Variable event_schedulerScope Global Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value ONValid Values ONOFFDISABLEDThis variable enables or disables, and starts or stops, the Event Scheduler. The possible status values are
ON,OFF, andDISABLED. Turning the Event SchedulerOFFis not the same as disabling the Event Scheduler, which requires setting the status toDISABLED. This variable and its effects on the Event Scheduler's operation are discussed in greater detail in Section 27.4.2, “Event Scheduler Configuration” -
Command-Line Format --explain-format=formatSystem Variable explain_formatScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value TRADITIONALValid Values TRADITIONALJSONTREEThis variable determines the default output format used by
EXPLAINin the absence of aFORMAToption when displaying a query execution plan. Possible values and their effects are listed here:TRADITIONAL: Use MySQL's traditional table-based output, as ifFORMAT=TRADITIONALhad been specified as part of theEXPLAINstatement. This is the variable's default value.DEFAULTis also supported as a synonym forTRADITIONAL, and has exactly the same effect.NoteDEFAULTcannot be used as part of anEXPLAINstatement'sFORMAToption.JSON: Use the JSON output format, as ifFORMAT=JSONhad been specified.TREE: Use the tree-based output format, as ifFORMAT=TREEhad been specified.
The setting for this variable also affects
EXPLAIN ANALYZE. For this purpose,DEFAULTandTRADITIONALare interpeted asTREE. If the value ofexplain_formatisJSONand anEXPLAIN ANALYZEstatement having noFORMAToption is issued, the statement raises an error (ER_NOT_SUPPORTED_YET).Using a format specifier with
EXPLAINorEXPLAIN ANALYZEoverrides any setting forexplain_format.The
explain_formatsystem variable has no effect onEXPLAINoutput when this statement is used to display information about table columns.Setting the session value of
explain_formatrequires no special privileges; setting it on the global level requiresSYSTEM_VARIABLES_ADMIN(or the deprecatedSUPERprivilege). See Section 7.1.9.1, “System Variable Privileges”.For more information and examples, see Obtaining Execution Plan Information.
-
Command-Line Format --explain-json-format-version=#System Variable explain_json_format_versionScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1Minimum Value 1Maximum Value 2Determines the version of the JSON output format used by
EXPLAIN FORMAT=JSONstatements. Setting this variable to1causes the server to use Version 1, which is the linear format used for output from such statements in older versions of MySQL; this is the default in MySQL 8.4. Settingexplain_json_format_versionto2causes the Version 2 format to be used; this JSON output format is based on access paths, and is intended to provide better compatibility with future versions of the MySQL Optimizer.For an example of use, see Obtaining Execution Plan Information.
explicit_defaults_for_timestampCommand-Line Format --explicit-defaults-for-timestamp[={OFF|ON}]Deprecated Yes System Variable explicit_defaults_for_timestampScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONThis system variable determines whether the server enables certain nonstandard behaviors for default values and
NULL-value handling inTIMESTAMPcolumns. By default,explicit_defaults_for_timestampis enabled, which disables the nonstandard behaviors. Disablingexplicit_defaults_for_timestampresults in a warning.If
explicit_defaults_for_timestampis disabled, the server enables the nonstandard behaviors and handlesTIMESTAMPcolumns as follows:TIMESTAMPcolumns not explicitly declared with theNULLattribute are automatically declared with theNOT NULLattribute. Assigning such a column a value ofNULLis permitted and sets the column to the current timestamp. Exception: Attempting to insertNULLinto a generated column declared asTIMESTAMP NOT NULLis rejected with an error.The first
TIMESTAMPcolumn in a table, if not explicitly declared with theNULLattribute or an explicitDEFAULTorON UPDATEattribute, is automatically declared with theDEFAULT CURRENT_TIMESTAMPandON UPDATE CURRENT_TIMESTAMPattributes.TIMESTAMPcolumns following the first one, if not explicitly declared with theNULLattribute or an explicitDEFAULTattribute, are automatically declared asDEFAULT '0000-00-00 00:00:00'(the “zero” timestamp). For inserted rows that specify no explicit value for such a column, the column is assigned'0000-00-00 00:00:00'and no warning occurs.Depending on whether strict SQL mode or the
NO_ZERO_DATESQL mode is enabled, a default value of'0000-00-00 00:00:00'may be invalid. Be aware that theTRADITIONALSQL mode includes strict mode andNO_ZERO_DATE. See Section 7.1.11, “Server SQL Modes”.
The nonstandard behaviors just described are deprecated; expect them to be removed in a future MySQL release.
If
explicit_defaults_for_timestampis enabled, the server disables the nonstandard behaviors and handlesTIMESTAMPcolumns as follows:It is not possible to assign a
TIMESTAMPcolumn a value ofNULLto set it to the current timestamp. To assign the current timestamp, set the column toCURRENT_TIMESTAMPor a synonym such asNOW().TIMESTAMPcolumns not explicitly declared with theNOT NULLattribute are automatically declared with theNULLattribute and permitNULLvalues. Assigning such a column a value ofNULLsets it toNULL, not the current timestamp.TIMESTAMPcolumns declared with theNOT NULLattribute do not permitNULLvalues. For inserts that specifyNULLfor such a column, the result is either an error for a single-row insert if strict SQL mode is enabled, or'0000-00-00 00:00:00'is inserted for multiple-row inserts with strict SQL mode disabled. In no case does assigning the column a value ofNULLset it to the current timestamp.TIMESTAMPcolumns explicitly declared with theNOT NULLattribute and without an explicitDEFAULTattribute are treated as having no default value. For inserted rows that specify no explicit value for such a column, the result depends on the SQL mode. If strict SQL mode is enabled, an error occurs. If strict SQL mode is not enabled, the column is declared with the implicit default of'0000-00-00 00:00:00'and a warning occurs. This is similar to how MySQL treats other temporal types such asDATETIME.No
TIMESTAMPcolumn is automatically declared with theDEFAULT CURRENT_TIMESTAMPorON UPDATE CURRENT_TIMESTAMPattributes. Those attributes must be explicitly specified.The first
TIMESTAMPcolumn in a table is not handled differently fromTIMESTAMPcolumns following the first one.
If
explicit_defaults_for_timestampis disabled at server startup, this warning appears in the error log:[Warning] TIMESTAMP with implicit DEFAULT value is deprecated. Please use --explicit_defaults_for_timestamp server option (see documentation for more details).As indicated by the warning, to disable the deprecated nonstandard behaviors, enable the
explicit_defaults_for_timestampsystem variable at server startup.Noteexplicit_defaults_for_timestampis itself deprecated because its only purpose is to permit control over deprecatedTIMESTAMPbehaviors that are to be removed in a future MySQL release. When removal of those behaviors occurs, expectexplicit_defaults_for_timestampto be removed as well.For additional information, see Section 13.2.5, “Automatic Initialization and Updating for TIMESTAMP and DATETIME”.
-
System Variable external_userScope Session Dynamic No SET_VARHint AppliesNo Type String The external user name used during the authentication process, as set by the plugin used to authenticate the client. With native (built-in) MySQL authentication, or if the plugin does not set the value, this variable is
NULL. See Section 8.2.19, “Proxy Users”. -
Command-Line Format --flush[={OFF|ON}]System Variable flushScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFApplies to MyISAM, only.
If
ON, the server flushes (synchronizes) all changes to disk after each SQL statement. Normally, MySQL does a write of all changes to disk only after each SQL statement and lets the operating system handle the synchronizing to disk. See Section B.3.3.3, “What to Do If MySQL Keeps Crashing”. This variable is set toONif you start mysqld with the--flushoption.NoteIf
flushis enabled, the value offlush_timedoes not matter and changes toflush_timehave no effect on flush behavior. -
Command-Line Format --flush-time=#System Variable flush_timeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 31536000Unit seconds If 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.NoteIf
flushis enabled, the value offlush_timedoes not matter and changes toflush_timehave no effect on flush behavior. -
System Variable foreign_key_checksScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value ONIf set to 1 (the default), foreign key constraints are checked. If set to 0, foreign key constraints are ignored, with a couple of exceptions. When re-creating a table that was dropped, an error is returned if the table definition does not conform to the foreign key constraints referencing the table. Likewise, an
ALTER TABLEoperation returns an error if a foreign key definition is incorrectly formed. For more information, see Section 15.1.20.5, “FOREIGN KEY Constraints”.Setting this variable has the same effect on
NDBtables as it does forInnoDBtables. Typically you leave this setting enabled during normal operation, to enforce referential integrity. Disabling foreign key checking can be useful for reloadingInnoDBtables in an order different from that required by their parent/child relationships. See Section 15.1.20.5, “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 = 0are not verified for consistency.Dropping an index required by a foreign key constraint is not permitted, even with
foreign_key_checks=0. The foreign key constraint must be removed before dropping the index. -
Command-Line Format --ft-boolean-syntax=nameSystem Variable ft_boolean_syntaxScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value + -><()~*:""&|The list of operators supported by boolean full-text searches performed using
IN BOOLEAN MODE. See Section 14.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 ft_max_word_lenScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 84Minimum Value 10Maximum Value 84The maximum length of the word to be included in a
MyISAMFULLTEXTindex.NoteFULLTEXTindexes onMyISAMtables must be rebuilt after changing this variable. UseREPAIR TABLE.tbl_nameQUICK -
Command-Line Format --ft-min-word-len=#System Variable ft_min_word_lenScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 4Minimum Value 1Maximum Value 82The minimum length of the word to be included in a
MyISAMFULLTEXTindex.NoteFULLTEXTindexes onMyISAMtables must be rebuilt after changing this variable. UseREPAIR TABLE.tbl_nameQUICK -
Command-Line Format --ft-query-expansion-limit=#System Variable ft_query_expansion_limitScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 20Minimum Value 0Maximum 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 ft_stopword_fileScope Global Dynamic No SET_VARHint AppliesNo Type File name The file from which to read the list of stopwords for full-text searches on
MyISAMtables. 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 thestorage/myisam/ft_static.cfile). Setting this variable to the empty string ('') disables stopword filtering. See also Section 14.9.4, “Full-Text Stopwords”.NoteFULLTEXTindexes onMyISAMtables must be rebuilt after changing this variable or the contents of the stopword file. UseREPAIR TABLE.tbl_nameQUICK -
Command-Line Format --general-log[={OFF|ON}]System Variable general_logScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value 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 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. -
Command-Line Format --general-log-file=file_nameSystem Variable general_log_fileScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value 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. generated_random_password_lengthCommand-Line Format --generated-random-password-length=#System Variable generated_random_password_lengthScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 20Minimum Value 5Maximum Value 255The maximum number of characters permitted in random passwords generated for
CREATE USER,ALTER USER, andSET PASSWORDstatements. For more information, see Random Password Generation.global_connection_memory_limitCommand-Line Format --global-connection-memory-limit=#System Variable global_connection_memory_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 18446744073709551615Minimum Value 16777216Maximum Value 18446744073709551615Unit bytes Set the total amount of memory that can be used by all user connections; that is,
Global_connection_memoryshould not exceed this amount. Any time that it does, all queries (including any currently running) from regular users are rejected withER_GLOBAL_CONN_LIMIT.Memory used by the system users such as the MySQL root user is included in this total, but is not counted towards the disconnection limit; such users are never disconnected due to memory usage.
Memory used by the
InnoDBbuffer pool is excluded from the total.You must have the
SYSTEM_VARIABLES_ADMINorSUPERprivilege to set this variable.global_connection_memory_trackingCommand-Line Format --global-connection-memory-tracking={TRUE|FALSE}System Variable global_connection_memory_trackingScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value FALSEDetermines whether the server calculates
Global_connection_memory. This variable must be enabled explicitly; otherwise, the memory calculation is not performed, andGlobal_connection_memoryis not set.You must have the
SYSTEM_VARIABLES_ADMINorSUPERprivilege to set this variable.-
Command-Line Format --group-concat-max-len=#System Variable group_concat_max_lenScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 1024Minimum Value 4Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295The maximum permitted result length in bytes for the
GROUP_CONCAT()function. The default is 1024. YESif thezlibcompression library is available to the server,NOif not. If not, theCOMPRESS()andUNCOMPRESS()functions cannot be used.YESif mysqld supports dynamic loading of plugins,NOif not. If the value isNO, you cannot use options such as--plugin-loadto load plugins at server startup, or theINSTALL PLUGINstatement to load plugins at runtime.YESif the server supports spatial data types,NOif not.YESif statement profiling capability is present,NOif not. If present, theprofilingsystem variable controls whether this capability is enabled or disabled. See Section 15.7.7.33, “SHOW PROFILES Statement”.This variable is deprecated; you should expect it to be removed in a future MySQL release.
have_query_cacheis deprecated, always has a value ofNO, and you should expect it to be removed in a future MySQL release.YESifRTREEindexes are available,NOif not. (These are used for spatial indexes inMyISAMtables.)-
System Variable have_statement_timeoutScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Whether the statement execution timeout feature is available (see Statement Execution Time Optimizer Hints). The value can be
NOif the background thread used by this feature could not be initialized. YESif symbolic link support is enabled,NOif not. This is required on Unix for support of theDATA DIRECTORYandINDEX DIRECTORYtable options. If the server is started with the--skip-symbolic-linksoption, the value isDISABLED.This variable has no meaning on Windows.
NoteSymbolic link support, along with the
--symbolic-linksoption that controls it, is deprecated; expect these to be removed in a future version of MySQL. In addition, the option is disabled by default. The relatedhave_symlinksystem variable also is deprecated and you should expect it to be removed in a future version of MySQL.histogram_generation_max_mem_sizeCommand-Line Format --histogram-generation-max-mem-size=#System Variable histogram_generation_max_mem_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 20000000Minimum Value 1000000Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295Unit bytes The maximum amount of memory available for generating histogram statistics. See Section 10.9.6, “Optimizer Statistics”, and Section 15.7.3.1, “ANALYZE TABLE Statement”.
Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --host-cache-size=#System Variable host_cache_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value -1(signifies autosizing; do not assign this literal value)Minimum Value 0Maximum Value 65536The MySQL server maintains an in-memory host cache that contains client host name and IP address information and is used to avoid Domain Name System (DNS) lookups; see Section 7.1.12.3, “DNS Lookups and the Host Cache”.
The
host_cache_sizevariable controls the size of the host cache, as well as the size of the Performance Schemahost_cachetable that exposes the cache contents. Settinghost_cache_sizehas these effects:Setting the size to 0 disables the host cache. With the cache disabled, the server performs a DNS lookup every time a client connects.
Changing the size at runtime causes an implicit host cache flushing operation that clears the host cache, truncates the
host_cachetable, and unblocks any blocked hosts.
The default value is autosized to 128, plus 1 for a value of
max_connectionsup to 500, plus 1 for every increment of 20 over 500 in themax_connectionsvalue, capped to a limit of 2000. -
The server sets this variable to the server host name at startup. The maximum length is 255 characters.
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 init_connectScope Global Dynamic Yes SET_VARHint AppliesNo Type String A string to be executed by the server for each client that connects. The string consists of one or more SQL statements, separated by semicolon characters.
For users that have the
CONNECTION_ADMINprivilege (or the deprecatedSUPERprivilege), the content ofinit_connectis not executed. 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 theCONNECTION_ADMINorSUPERprivilege enables them to open a connection and fix theinit_connectvalue.init_connectexecution is skipped for any client user with an expired password. This is done because such a user cannot execute arbitrary statements, and thusinit_connectexecution fails, leaving the client unable to connect. Skippinginit_connectexecution enables the user to connect and change password.The server discards any result sets produced by statements in the value of
init_connect. information_schema_stats_expiryCommand-Line Format --information-schema-stats-expiry=#System Variable information_schema_stats_expiryScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 86400Minimum Value 0Maximum Value 31536000Unit seconds Some
INFORMATION_SCHEMAtables contain columns that provide table statistics:STATISTICS.CARDINALITY TABLES.AUTO_INCREMENT TABLES.AVG_ROW_LENGTH TABLES.CHECKSUM TABLES.CHECK_TIME TABLES.CREATE_TIME TABLES.DATA_FREE TABLES.DATA_LENGTH TABLES.INDEX_LENGTH TABLES.MAX_DATA_LENGTH TABLES.TABLE_ROWS TABLES.UPDATE_TIMEThose columns represent dynamic table metadata; that is, information that changes as table contents change.
By default, MySQL retrieves cached values for those columns from the
mysql.index_statsandmysql.table_statsdictionary tables when the columns are queried, which is more efficient than retrieving statistics directly from the storage engine. If cached statistics are not available or have expired, MySQL retrieves the latest statistics from the storage engine and caches them in themysql.index_statsandmysql.table_statsdictionary tables. Subsequent queries retrieve the cached statistics until the cached statistics expire. A server restart or the first opening of themysql.index_statsandmysql.table_statstables do not update cached statistics automatically.The
information_schema_stats_expirysession variable defines the period of time before cached statistics expire. The default is 86400 seconds (24 hours), but the time period can be extended to as much as one year.To update cached values at any time for a given table, use
ANALYZE TABLE.To always retrieve the latest statistics directly from the storage engine and bypass cached values, set
information_schema_stats_expiryto0.Querying statistics columns does not store or update statistics in the
mysql.index_statsandmysql.table_statsdictionary tables under these circumstances:When cached statistics have not expired.
When
information_schema_stats_expiryis set to 0.When the server is in
read_only,super_read_only,transaction_read_only, orinnodb_read_onlymode.When the query also fetches Performance Schema data.
The statistics cache may be updated during a multiple-statement transaction before it is known whether the transaction commits. As a result, the cache may contain information that does not correspond to a known committed state. This can occur with
autocommit=0or afterSTART TRANSACTION.information_schema_stats_expiryis a session variable, and each client session can define its own expiration value. Statistics that are retrieved from the storage engine and cached by one session are available to other sessions.For related information, see Section 10.2.3, “Optimizing INFORMATION_SCHEMA Queries”.
-
Command-Line Format --init-file=file_nameSystem Variable init_fileScope Global Dynamic No SET_VARHint AppliesNo Type File name If specified, this variable names a file containing SQL statements to be read and executed during the startup process. The acceptable format for statements in this file support the following constructs:
delimiter ;, to set the statement delimiter to the;character.delimiter $$, to set the statement delimiter to the$$character sequence.Multiple statements on the same line, delimited by the current delimiter.
Multiple-line statements.
Comments from a
#character to the end of the line.Comments from a
--sequence to the end of the line.C-style comments from a
/*sequence to the following*/sequence, including over multiple lines.Multiple-line string literals enclosed within either single quote (
') or double quote (") characters.
If the server is started with the
--initializeor--initialize-insecureoption, it operates in bootstrap mode and some functionality is unavailable that limits the statements permitted in the file. These include statements that relate to account management (such asCREATE USERorGRANT), replication, and global transaction identifiers. See Section 19.1.3, “Replication with Global Transaction Identifiers”.Threads created during server startup are used for tasks such as creating the data dictionary, running upgrade procedures, and creating system tables. To ensure a stable and predictable environment, these threads are executed with the server built-in defaults for some system variables, such as
sql_mode,character_set_server,collation_server,completion_type,explicit_defaults_for_timestamp, anddefault_table_encryption.These threads are also used to execute the statements in any file specified with
init_filewhen starting the server, so such statements execute with the server's built-in default values for those system variables. innodb_xxxInnoDBsystem variables are listed in Section 17.14, “InnoDB Startup Options and System Variables”. These variables control many aspects of storage, memory use, and I/O patterns forInnoDBtables, and are especially important now thatInnoDBis 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 interactive_timeoutScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 28800Minimum Value 1Maximum Value 31536000Unit seconds The number of seconds the server waits for activity on an interactive connection before closing it. An interactive client is defined as a client that uses the
CLIENT_INTERACTIVEoption tomysql_real_connect(). See alsowait_timeout. internal_tmp_mem_storage_engineCommand-Line Format --internal-tmp-mem-storage-engine=#System Variable internal_tmp_mem_storage_engineScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Enumeration Default Value TempTableValid Values MEMORYTempTableThe storage engine for in-memory internal temporary tables (see Section 10.4.4, “Internal Temporary Table Use in MySQL”). Permitted values are
TempTable(the default) andMEMORY.The optimizer uses the storage engine defined by
internal_tmp_mem_storage_enginefor in-memory internal temporary tables.Configuring a session setting for
internal_tmp_mem_storage_enginerequires theSESSION_VARIABLES_ADMINorSYSTEM_VARIABLES_ADMINprivilege.-
Command-Line Format --join-buffer-size=#System Variable join_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 262144Minimum Value 128Maximum Value (Windows) 4294967168Maximum Value (Other, 64-bit platforms) 18446744073709551488Maximum Value (Other, 32-bit platforms) 4294967168Unit bytes Block Size 128The 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. This variable also controls the amount of memory used for hash joins. 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.The default is 256KB. The maximum permissible setting for
join_buffer_sizeis 4GB−1. Larger values are permitted for 64-bit platforms (except 64-bit Windows, for which large values are truncated to 4GB−1 with a warning). The block size is 128, and a value that is not an exact multiple of the block size is rounded down to the next lower multiple of the block size by MySQL Server before storing the value for the system variable. The parser allows values up to the maximum unsigned integer value for the platform (4294967295 or 232−1 for a 32-bit system, 18446744073709551615 or 264−1 for a 64-bit system) but the actual maximum is a block size lower.Unless a Block Nested-Loop or Batched Key Access algorithm is used, 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 the session setting to a larger value only in sessions that are doing large joins, or change the setting on a per-query basis by using a
SET_VARoptimizer hint (see Section 10.9.3, “Optimizer Hints”). Memory allocation time can cause substantial performance drops if the global size is larger than needed by most queries that use it.When Block Nested-Loop is used, a larger join buffer can be beneficial up to the point where all required columns from all rows in the first table are stored in the join buffer. This depends on the query; the optimal size may be smaller than holding all rows from the first tables.
When Batched Key Access is used, the value of
join_buffer_sizedefines how large the batch of keys is in each request to the storage engine. The larger the buffer, the more sequential access is made to the right hand table of a join operation, which can significantly improve performance.For additional information about join buffering, see Section 10.2.1.7, “Nested-Loop Join Algorithms”. For information about Batched Key Access, see Section 10.2.1.12, “Block Nested-Loop and Batched Key Access Joins”. For information about hash joins, see Section 10.2.1.4, “Hash Join Optimization”.
-
Command-Line Format --keep-files-on-create[={OFF|ON}]System Variable keep_files_on_createScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value 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 caseMyISAMdoes 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 does not overwrite a file in the specified directory. -
Command-Line Format --key-buffer-size=#System Variable key_buffer_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8388608Minimum Value 0Maximum Value (64-bit platforms) OS_PER_PROCESS_LIMITMaximum Value (32-bit platforms) 4294967295Unit bytes Index 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 minimum permissible setting is 0, but you cannot set
key_buffer_sizeto 0 dynamically. A setting of 0 drops the key cache, which is not permitted at runtime. Settingkey_buffer_sizeto 0 is permitted only at startup, in which case the key cache is not initialized. Changing thekey_buffer_sizesetting at runtime from a value of 0 to a permitted non-zero value initializes the key cache.key_buffer_sizecan be increased or decreased only in increments or multiples of 4096 bytes. Increasing or decreasing the setting by a nonconforming value produces a warning and truncates the setting to a conforming value.The maximum permissible setting for
key_buffer_sizeis 4GB−1 on 32-bit platforms. Larger values are permitted for 64-bit platforms. 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 10.2.5.1, “Optimizing 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 15.7.7, “SHOW Statements”.) 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 10.10.2, “The MyISAM Key Cache”. -
Command-Line Format --key-cache-age-threshold=#System Variable key_cache_age_thresholdScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 300Minimum Value 100Maximum Value (64-bit platforms) 18446744073709551516Maximum Value (32-bit platforms) 4294967196Block Size 100This 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 10.10.2, “The MyISAM Key Cache”.
-
Command-Line Format --key-cache-block-size=#System Variable key_cache_block_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1024Minimum Value 512Maximum Value 16384Unit bytes Block Size 512The size in bytes of blocks in the key cache. The default value is 1024. See Section 10.10.2, “The MyISAM Key Cache”.
-
Command-Line Format --key-cache-division-limit=#System Variable key_cache_division_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 100Minimum Value 1Maximum 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 10.10.2, “The MyISAM Key Cache”.
-
System Variable large_files_supportScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Whether mysqld was compiled with options for large file support.
-
Command-Line Format --large-pages[={OFF|ON}]System Variable large_pagesScope Global Dynamic No SET_VARHint AppliesNo Platform Specific Linux Type Boolean Default Value OFFWhether large page support is enabled (via the
--large-pagesoption). See Section 10.12.3.3, “Enabling Large Page Support”. -
System Variable large_page_sizeScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 65535Unit bytes If large page support is enabled, this shows the size of memory pages. Large memory pages are supported only on Linux; on other platforms, the value of this variable is always 0. See Section 10.12.3.3, “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.-
Command-Line Format --lc-messages=nameSystem Variable lc_messagesScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value en_USThe locale to use for error messages. The default is
en_US. The server converts the argument to a language name and combines it with the value oflc_messages_dirto produce the location for the error message file. See Section 12.12, “Setting the Error Message Language”. -
Command-Line Format --lc-messages-dir=dir_nameSystem Variable lc_messages_dirScope Global Dynamic No SET_VARHint AppliesNo Type Directory name The directory where error messages are located. The server uses the value together with the value of
lc_messagesto produce the location for the error message file. See Section 12.12, “Setting the Error Message Language”. -
Command-Line Format --lc-time-names=valueSystem Variable lc_time_namesScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String This variable specifies the locale that controls the language used to display day and month names and abbreviations. This variable affects the output from the
DATE_FORMAT(),DAYNAME()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 12.16, “MySQL Server Locale Support”. -
System Variable licenseScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value GPLThe type of license the server has.
-
Command-Line Format --local-infile[={OFF|ON}]System Variable local_infileScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable controls server-side
LOCALcapability forLOAD DATAstatements. Depending on thelocal_infilesetting, the server refuses or permits local data loading by clients that haveLOCALenabled on the client side.To explicitly cause the server to refuse or permit
LOAD DATA LOCALstatements (regardless of how client programs and libraries are configured at build time or runtime), start mysqld withlocal_infiledisabled or enabled, respectively.local_infilecan also be set at runtime. For more information, see Section 8.1.6, “Security Considerations for LOAD DATA LOCAL”. -
Command-Line Format --lock-wait-timeout=#System Variable lock_wait_timeoutScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 31536000Minimum Value 1Maximum Value 31536000Unit seconds This variable specifies the timeout in seconds for attempts to acquire metadata locks. The permissible values range from 1 to 31536000 (1 year). The default is 31536000.
This timeout applies to all statements that use metadata locks. These include DML and DDL operations on tables, views, stored procedures, and stored functions, as well as
LOCK TABLES,FLUSH TABLES WITH READ LOCK, andHANDLERstatements.This timeout does not apply to implicit accesses to system tables in the
mysqldatabase, such as grant tables modified byGRANTorREVOKEstatements or table logging statements. The timeout does apply to system tables accessed directly, such as withSELECTorUPDATE.The timeout value applies separately for each metadata lock attempt. A given statement can require more than one lock, so it is possible for the statement to block for longer than the
lock_wait_timeoutvalue before reporting a timeout error. When lock timeout occurs,ER_LOCK_WAIT_TIMEOUTis reported.lock_wait_timeoutalso defines the amount of time that aLOCK INSTANCE FOR BACKUPstatement waits for a lock before giving up. -
System Variable locked_in_memoryScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFF -
Command-Line Format --log-error[=file_name]System Variable log_errorScope Global Dynamic No SET_VARHint AppliesNo Type File name The default error log destination. If the destination is the console, the value is
stderr. Otherwise, the destination is a file and thelog_errorvalue is the file name. See Section 7.4.2, “The Error Log”. -
Command-Line Format --log-error-services=valueSystem Variable log_error_servicesScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value log_filter_internal; log_sink_internalThe components to enable for error logging. The variable may contain a list with 0, 1, or many elements. In the latter case, elements may be delimited by semicolons or commas, optionally followed by space. A given setting cannot use both semicolon and comma separators. Component order is significant because the server executes components in the order listed.
Any loadable (not built in) component named in
log_error_servicesis implicitly loaded if it is not already loaded. For more information, see Section 7.4.2.1, “Error Log Configuration”. -
Command-Line Format --log-error-suppression-list=valueSystem Variable log_error_suppression_listScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value empty stringThe
log_error_suppression_listsystem variable applies to events intended for the error log and specifies which events to suppress when they occur with a priority ofWARNINGorINFORMATION. For example, if a particular type of warning is considered undesirable “noise” in the error log because it occurs frequently but is not of interest, it can be suppressed. This variable affects filtering performed by thelog_filter_internalerror log filter component, which is enabled by default (see Section 7.5.3, “Error Log Components”). Iflog_filter_internalis disabled,log_error_suppression_listhas no effect.The
log_error_suppression_listvalue may be the empty string for no suppression, or a list of one or more comma-separated values indicating the error codes to suppress. Error codes may be specified in symbolic or numeric form. A numeric code may be specified with or without theMY-prefix. Leading zeros in the numeric part are not significant. Examples of permitted code formats:ER_SERVER_SHUTDOWN_COMPLETE MY-000031 000031 MY-31 31Symbolic values are preferable to numeric values for readability and portability. For information about the permitted error symbols and numbers, see MySQL 8.4 Error Message Reference.
The effect of
log_error_suppression_listcombines with that oflog_error_verbosity. For additional information, see Section 7.4.2.5, “Priority-Based Error Log Filtering (log_filter_internal)”. -
Command-Line Format --log-error-verbosity=#System Variable log_error_verbosityScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 2Minimum Value 1Maximum Value 3The
log_error_verbositysystem variable specifies the verbosity for handling events intended for the error log. This variable affects filtering performed by thelog_filter_internalerror log filter component, which is enabled by default (see Section 7.5.3, “Error Log Components”). Iflog_filter_internalis disabled,log_error_verbosityhas no effect.Events intended for the error log have a priority of
ERROR,WARNING, orINFORMATION.log_error_verbositycontrols verbosity based on which priorities to permit for messages written to the log, as shown in the following table.log_error_verbosity Value Permitted Message Priorities 1 ERROR2 ERROR,WARNING3 ERROR,WARNING,INFORMATIONThere is also a priority of
SYSTEM. System messages about non-error situations are printed to the error log regardless of thelog_error_verbosityvalue. These messages include startup and shutdown messages, and some significant changes to settings.The effect of
log_error_verbositycombines with that oflog_error_suppression_list. For additional information, see Section 7.4.2.5, “Priority-Based Error Log Filtering (log_filter_internal)”. -
Command-Line Format --log-output=nameSystem Variable log_outputScope Global Dynamic Yes SET_VARHint AppliesNo Type Set Default Value FILEValid Values TABLEFILENONEThe destination or destinations for general query log and slow query log output. The value is a list one or more comma-separated words chosen from
TABLE,FILE, andNONE.TABLEselects logging to thegeneral_logandslow_logtables in themysqlsystem schema.FILEselects logging to log files.NONEdisables logging. IfNONEis present in the value, it takes precedence over any other words that are present.TABLEandFILEcan both be given to select both log output destinations.This variable selects log output destinations, but does not enable log output. To do that, enable the
general_logandslow_query_logsystem variables. ForFILElogging, thegeneral_log_fileandslow_query_log_filesystem variables determine the log file locations. For more information, see Section 7.4.1, “Selecting General Query Log and Slow Query Log Output Destinations”. -
Command-Line Format --log-queries-not-using-indexes[={OFF|ON}]System Variable log_queries_not_using_indexesScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIf you enable this variable with the slow query log enabled, queries that are expected to retrieve all rows are logged. See Section 7.4.5, “The Slow Query Log”. This option does not necessarily mean that no index is used. For example, a query that uses a full index scan uses an index but would be logged because the index would not limit the number of rows.
-
Command-Line Format --log-raw[={OFF|ON}]System Variable log_rawScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThe
log_rawsystem variable is initially set to the value of the--log-rawoption. See the description of that option for more information. The system variable may also be set at runtime to change password masking behavior. -
Command-Line Format --log-slow-admin-statements[={OFF|ON}]System Variable log_slow_admin_statementsScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFInclude slow administrative statements in the statements written to the slow query log. Administrative statements include
ALTER TABLE,ANALYZE TABLE,CHECK TABLE,CREATE INDEX,DROP INDEX,OPTIMIZE TABLE, andREPAIR TABLE. -
Command-Line Format --log-slow-extra[={OFF|ON}]System Variable log_slow_extraScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIf the slow query log is enabled and the output destination includes
FILE, the server writes additional fields to log file lines that provide information about slow statements. See Section 7.4.5, “The Slow Query Log”.TABLEoutput is unaffected. -
Command-Line Format --log-timestamps=#System Variable log_timestampsScope Global Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value UTCValid Values UTCSYSTEMThis variable controls the time zone of timestamps in messages written to the error log, and in general query log and slow query log messages written to files. It does not affect the time zone of general query log and slow query log messages written to tables (
mysql.general_log,mysql.slow_log). Rows retrieved from those tables can be converted from the local system time zone to any desired time zone withCONVERT_TZ()or by setting the sessiontime_zonesystem variable.Permitted
log_timestampsvalues areUTC(the default) andSYSTEM(the local system time zone).Timestamps are written using ISO 8601 / RFC 3339 format:
plus a tail value ofYYYY-MM-DDThh:mm:ss.uuuuuuZsignifying Zulu time (UTC) or±hh:mm(an offset from UTC). log_throttle_queries_not_using_indexesCommand-Line Format --log-throttle-queries-not-using-indexes=#System Variable log_throttle_queries_not_using_indexesScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 4294967295If
log_queries_not_using_indexesis enabled, thelog_throttle_queries_not_using_indexesvariable limits the number of such queries per minute that can be written to the slow query log. A value of 0 (the default) means “no limit”. For more information, see Section 7.4.5, “The Slow Query Log”.-
Command-Line Format --long-query-time=#System Variable long_query_timeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Numeric Default Value 10Minimum Value 0Maximum Value 31536000Unit seconds If 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 minimum and default values oflong_query_timeare 0 and 10, respectively. The maximum is 31536000, which is 365 days in seconds. The value can be specified to a resolution of microseconds. See Section 7.4.5, “The Slow Query Log”.Smaller values of this variable result in more statements being considered long-running, with the result that more space is required for the slow query log. For very small values (less than one second), the log may grow quite large in a small time. Increasing the number of statements considered long-running may also result in false positives for the “excessive Number of Long Running Processes” alert in MySQL Enterprise Monitor, especially if Group Replication is enabled. For these reasons, very small values should be used in test environments only, or, in production environments, only for a short period.
mysqldump performs a full table scan, which means its queries can often exceed a
long_query_timesetting that is useful for regular queries. If you want to exclude most or all of the queries generated by mysqldump from the slow query log, you can use--mysqld-long-query-timeto change the session value of the system variable to a higher value. -
Command-Line Format --low-priority-updates[={OFF|ON}]System Variable low_priority_updatesScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIf set to
1, allINSERT,UPDATE,DELETE, andLOCK TABLE WRITEstatements wait until there is no pendingSELECTorLOCK TABLE READon the affected table. The same effect can be obtained using{INSERT | REPLACE | DELETE | UPDATE} LOW_PRIORITY ...to lower the priority of only one query. This variable affects only storage engines that use only table-level locking (such asMyISAM,MEMORY, andMERGE). See Section 10.11.2, “Table Locking Issues”.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
System Variable lower_case_file_systemScope Global Dynamic No SET_VARHint AppliesNo Type Boolean This 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 lower_case_table_namesScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value (macOS) 2Default Value (Unix) 0Default Value (Windows) 1Minimum Value 0Maximum 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 details, see Section 11.2.3, “Identifier Case Sensitivity”.
The default value of this variable is platform-dependent (see
lower_case_file_system). On Linux and other Unix-like systems, the default is0. On Windows the default value is1. On macOS, the default value is2. On Linux (and other Unix-like systems), setting the value to2is not supported; the server forces the value to0instead.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 macOS). It is an unsupported combination that could result in a hang condition when running anINSERT INTO ... SELECT ... FROMoperation with the wrongtbl_nametbl_namelettercase. WithMyISAM, accessing table names using different lettercases could cause index corruption.An error message is printed and the server exits if you attempt to start the server with
--lower_case_table_names=0on a case-insensitive file system.The setting of this variable affects the behavior of replication filtering options with regard to case sensitivity. For more information, see Section 19.2.5, “How Servers Evaluate Replication Filtering Rules”.
It is prohibited to start the server with a
lower_case_table_namessetting that is different from the setting used when the server was initialized. The restriction is necessary because collations used by various data dictionary table fields are determined by the setting defined when the server is initialized, and restarting the server with a different setting would introduce inconsistencies with respect to how identifiers are ordered and compared.It is therefore necessary to configure
lower_case_table_namesto the desired setting before initializing the server. In most cases, this requires configuringlower_case_table_namesin a MySQL option file before starting the MySQL server for the first time. For APT installations on Debian and Ubuntu, however, the server is initialized for you, and there is no opportunity to configure the setting in an option file beforehand. You must therefore use thedebconf-set-selectionutility prior to installing MySQL using APT to enablelower_case_table_names. To do so, run this command before installing MySQL using APT:$> sudo debconf-set-selections <<< "mysql-server mysql-server/lowercase-table-names select Enabled" -
Command-Line Format --mandatory-roles=valueSystem Variable mandatory_rolesScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value empty stringRoles the server should treat as mandatory. In effect, these roles are automatically granted to every user, although setting
mandatory_rolesdoes not actually change any user accounts, and the granted roles are not visible in themysql.role_edgessystem table.The variable value is a comma-separated list of role names. Example:
SET PERSIST mandatory_roles = '`role1`@`%`,`role2`,role3,role4@localhost';Setting the runtime value of
mandatory_rolesrequires theROLE_ADMINprivilege, in addition to theSYSTEM_VARIABLES_ADMINprivilege (or the deprecatedSUPERprivilege) normally required to set a global system variable runtime value.Role names consist of a user part and host part in
format. The host part, if omitted, defaults touser_name@host_name%. For additional information, see Section 8.2.5, “Specifying Role Names”.The
mandatory_rolesvalue is a string, so user names and host names, if quoted, must be written in a fashion permitted for quoting within quoted strings.Roles named in the value of
mandatory_rolescannot be revoked withREVOKEor dropped withDROP ROLEorDROP USER.To prevent sessions from being made system sessions by default, a role that has the
SYSTEM_USERprivilege cannot be listed in the value of themandatory_rolessystem variable:If
mandatory_rolesis assigned a role at startup that has theSYSTEM_USERprivilege, the server writes a message to the error log and exits.If
mandatory_rolesis assigned a role at runtime that has theSYSTEM_USERprivilege, an error occurs and themandatory_rolesvalue remains unchanged.
Mandatory roles, like explicitly granted roles, do not take effect until activated (see Activating Roles). At login time, role activation occurs for all granted roles if the
activate_all_roles_on_loginsystem variable is enabled; otherwise, or for roles that are set as default roles otherwise. At runtime,SET ROLEactivates roles.Roles that do not exist when assigned to
mandatory_rolesbut are created later may require special treatment to be considered mandatory. For details, see Defining Mandatory Roles.SHOW GRANTSdisplays mandatory roles according to the rules described in Section 15.7.7.22, “SHOW GRANTS Statement”. -
Command-Line Format --max-allowed-packet=#System Variable max_allowed_packetScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 67108864Minimum Value 1024Maximum Value 1073741824Unit bytes Block Size 1024The maximum size of one packet or any generated/intermediate string, or any parameter sent by the
mysql_stmt_send_long_data()C API function. The default is 64MB.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.The session value of this variable is read only. The client can receive up to as many bytes as the session value. However, the server does 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 max_connect_errorsScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 100Minimum Value 1Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295After
max_connect_errorssuccessive connection requests from a host are interrupted without a successful connection, the server blocks that host from further connections. If a connection from a host is established successfully within fewer thanmax_connect_errorsattempts after a previous connection was interrupted, the error count for the host is cleared to zero. To unblock blocked hosts, flush the host cache; see Flushing the Host Cache. -
Command-Line Format --max-connections=#System Variable max_connectionsScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 151Minimum Value 1Maximum Value 100000The maximum permitted number of simultaneous client connections. The maximum effective value is the lesser of the effective value of
open_files_limit- 810, and the value actually set formax_connections.For more information, see Section 7.1.12.1, “Connection Interfaces”.
-
Command-Line Format --max-delayed-threads=#Deprecated Yes System Variable max_delayed_threadsScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 20Minimum Value 0Maximum Value 16384This system variable is deprecated (because
DELAYEDinserts are not supported) and subject to removal in a future MySQL release.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --max-digest-length=#System Variable max_digest_lengthScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 1024Minimum Value 0Maximum Value 1048576Unit bytes The maximum number of bytes of memory reserved per session for computation of normalized statement digests. Once that amount of space is used during digest computation, truncation occurs: no further tokens from a parsed statement are collected or figure into its digest value. Statements that differ only after that many bytes of parsed tokens produce the same normalized statement digest and are considered identical if compared or if aggregated for digest statistics.
The length used for calculating a normalized statement digest is the sum of the length of the normalized statement digest and the length of the statement digest. Since the length of the statement digest is always 64, this is equivalent to
LENGTH(STATEMENT_DIGEST_TEXT(. This means that, when the value ofstatement) ) + 64max_digest_lengthis 1024 (the default), the maximum length for a normalized SQL statement before truncation occurs is in effect 960 bytes.WarningSetting
max_digest_lengthto zero disables digest production, which also disables server functionality that requires digests, such as MySQL Enterprise Firewall.Decreasing the
max_digest_lengthvalue reduces memory use but causes the digest value of more statements to become indistinguishable if they differ only at the end. Increasing the value permits longer statements to be distinguished but increases memory use, particularly for workloads that involve large numbers of simultaneous sessions (the server allocatesmax_digest_lengthbytes per session).The parser uses this system variable as a limit on the maximum length of normalized statement digests that it computes. The Performance Schema, if it tracks statement digests, makes a copy of the digest value, using the
performance_schema_max_digest_length. system variable as a limit on the maximum length of digests that it stores. Consequently, ifperformance_schema_max_digest_lengthis less thanmax_digest_length, digest values stored in the Performance Schema are truncated relative to the original digest values.For more information about statement digesting, see Section 29.10, “Performance Schema Statement Digests and Sampling”.
-
Command-Line Format --max-error-count=#System Variable max_error_countScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 1024Minimum Value 0Maximum Value 65535The maximum number of error, warning, and information messages to be stored for display by the
SHOW ERRORSandSHOW WARNINGSstatements. This is the same as the number of condition areas in the diagnostics area, and thus the number of conditions that can be inspected byGET DIAGNOSTICS.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --max-execution-time=#System Variable max_execution_timeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 0Minimum Value 0Maximum Value 4294967295Unit milliseconds The execution timeout for
SELECTstatements, in milliseconds. If the value is 0, timeouts are not enabled.max_execution_timeapplies as follows:The global
max_execution_timevalue provides the default for the session value for new connections. The session value applies toSELECTexecutions executed within the session that include noMAX_EXECUTION_TIME(optimizer hint or for whichN)Nis 0.max_execution_timeapplies to read-onlySELECTstatements. Statements that are not read only are those that invoke a stored function that modifies data as a side effect.max_execution_timeis ignored forSELECTstatements in stored programs.
-
Command-Line Format --max-heap-table-size=#System Variable max_heap_table_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 16777216Minimum Value 16384Maximum Value (64-bit platforms) 18446744073709550592Maximum Value (32-bit platforms) 4294966272Unit bytes Block Size 1024This 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 existing
MEMORYtable, 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 10.4.4, “Internal Temporary Table Use in MySQL”.max_heap_table_sizeis not replicated. See Section 19.5.1.21, “Replication and MEMORY Tables”, and Section 19.5.1.39, “Replication and Variables”, for more information. -
Deprecated Yes System Variable max_insert_delayed_threadsScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 20Maximum Value 16384This variable is a synonym for
max_delayed_threads. Likemax_delayed_threads, it is deprecated (becauseDELAYEDinserts are not supported) and subject to removal in a future MySQL release.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --max-join-size=#System Variable max_join_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 18446744073709551615Minimum Value 1Maximum Value 18446744073709551615This represents a limit on the maximum number of row accesses in base tables made by a join. If the server's estimate indicates that a greater number of rows than
max_join_sizemust be read from the base tables, the statement is rejected with an error.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. -
Command-Line Format --max-length-for-sort-data=#Deprecated Yes System Variable max_length_for_sort_dataScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 4096Minimum Value 4Maximum Value 8388608Unit bytes This variable is deprecated, and has no effect in MySQL 8.4.
-
Command-Line Format --max-points-in-geometry=#System Variable max_points_in_geometryScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 65536Minimum Value 3Maximum Value 1048576The maximum value of the
points_per_circleargument to theST_Buffer_Strategy()function. -
Command-Line Format --max-prepared-stmt-count=#System Variable max_prepared_stmt_countScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 16382Minimum Value 0Maximum Value 4194304This variable limits the total number of prepared statements in the server. 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. Setting the value to 0 disables prepared statements.
-
Command-Line Format --max-seeks-for-key=#System Variable max_seeks_for_keyScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value (Windows) 4294967295Default Value (Other, 64-bit platforms) 18446744073709551615Default Value (Other, 32-bit platforms) 4294967295Minimum Value 1Maximum Value (Windows) 4294967295Maximum Value (Other, 64-bit platforms) 18446744073709551615Maximum Value (Other, 32-bit platforms) 4294967295Limit 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 15.7.7.23, “SHOW INDEX Statement”). 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 max_sort_lengthScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 1024Minimum Value 4Maximum Value 8388608Unit bytes The number of bytes to use when sorting string values which use
PAD SPACEcollations. The server uses only the firstmax_sort_lengthbytes of any such value and ignores the rest. Consequently, such values that differ only after the firstmax_sort_lengthbytes compare as equal forGROUP BY,ORDER BY, andDISTINCToperations. (This behavior differs from previous versions of MySQL, where this setting was applied to all values used in comparisons.)Increasing the value of
max_sort_lengthmay require increasing the value ofsort_buffer_sizeas well. For details, see Section 10.2.1.16, “ORDER BY Optimization” -
Command-Line Format --max-sp-recursion-depth[=#]System Variable max_sp_recursion_depthScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum 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. -
Command-Line Format --max-user-connections=#System Variable max_user_connectionsScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum 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
CREATE USERorALTER USERstatement. See Section 8.2.21, “Setting Account Resource Limits”. -
Command-Line Format --max-write-lock-count=#System Variable max_write_lock_countScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value (Windows) 4294967295Default Value (Other, 64-bit platforms) 18446744073709551615Default Value (Other, 32-bit platforms) 4294967295Minimum Value 1Maximum Value (Windows) 4294967295Maximum Value (Other, 64-bit platforms) 18446744073709551615Maximum Value (Other, 32-bit platforms) 4294967295After this many write locks, permit some pending read lock requests to be processed in between. Write lock requests have higher priority than read lock requests. However, if
max_write_lock_countis set to some low value (say, 10), read lock requests may be preferred over pending write lock requests if the read lock requests have already been passed over in favor of 10 write lock requests. Normally this behavior does not occur becausemax_write_lock_countby default has a very large value. -
Command-Line Format --mecab-rc-file=file_nameSystem Variable mecab_rc_fileScope Global Dynamic No SET_VARHint AppliesNo Type File name The
mecab_rc_fileoption is used when setting up the MeCab full-text parser.The
mecab_rc_fileoption defines the path to themecabrcconfiguration file, which is the configuration file for MeCab. The option is read-only and can only be set at startup. Themecabrcconfiguration file is required to initialize MeCab.For information about the MeCab full-text parser, see Section 14.9.9, “MeCab Full-Text Parser Plugin”.
For information about options that can be specified in the MeCab
mecabrcconfiguration file, refer to the MeCab Documentation on the Google Developers site. -
Command-Line Format --min-examined-row-limit=#System Variable min_examined_row_limitScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295Queries that examine fewer than this number of rows are not logged to the slow query log.
Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --myisam-data-pointer-size=#System Variable myisam_data_pointer_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 6Minimum Value 2Maximum Value 7Unit bytes The 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.3.2.10, “The table is full”. -
Command-Line Format --myisam-max-sort-file-size=#System Variable myisam_max_sort_file_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value (Windows) 2146435072Default Value (Other, 64-bit platforms) 9223372036853727232Default Value (Other, 32-bit platforms) 2147483648Minimum Value 0Maximum Value (Windows) 2146435072Maximum Value (Other, 64-bit platforms) 9223372036853727232Maximum Value (Other, 32-bit platforms) 2147483648Unit bytes The maximum size of the temporary file that MySQL is permitted to use while re-creating a
MyISAMindex (duringREPAIR TABLE,ALTER TABLE, orLOAD DATA). 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. -
Command-Line Format --myisam-mmap-size=#System Variable myisam_mmap_sizeScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value (64-bit platforms) 18446744073709551615Default Value (32-bit platforms) 4294967295Minimum Value 7Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295Unit bytes The 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. -
Command-Line Format --myisam-recover-options[=list]System Variable myisam_recover_optionsScope Global Dynamic No SET_VARHint AppliesNo Type Enumeration Default Value OFFValid Values OFFDEFAULTBACKUPFORCEQUICKSet the
MyISAMstorage engine recovery mode. The variable value is any combination of the values ofOFF,DEFAULT,BACKUP,FORCE, orQUICK. If you specify multiple values, separate them by commas. Specifying the variable with no value at server startup is the same as specifyingDEFAULT, and specifying with an explicit value of""disables recovery (same as a value ofOFF). If recovery is enabled, each time mysqld opens aMyISAMtable, it checks whether the table is marked as crashed or was not closed properly. (The last option works only if you are running with external locking disabled.) If this is the case, mysqld runs a check on the table. If the table was corrupted, mysqld attempts to repair it.The following options affect how the repair works.
Option Description OFFNo recovery. DEFAULTRecovery without backup, forcing, or quick checking. BACKUPIf the data file was changed during recovery, save a backup of the file astbl_name.MYD.tbl_name-datetime.BAKFORCERun recovery even if we would lose more than one row from the .MYDfile.QUICKDo not check the rows in the table if there are not any delete blocks. Before the server automatically repairs a table, it writes a note about the repair to the error log. If you want to be able to recover from most problems without user intervention, you should use the options
BACKUP,FORCE. This forces a repair of a table even if some rows would be deleted, but it keeps the old data file as a backup so that you can later examine what happened. -
Command-Line Format --myisam-sort-buffer-size=#System Variable myisam_sort_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8388608Minimum Value 4096Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295Unit bytes The size of the buffer that is allocated when sorting
MyISAMindexes during aREPAIR TABLEor when creating indexes withCREATE INDEXorALTER TABLE. -
Command-Line Format --myisam-stats-method=nameSystem Variable myisam_stats_methodScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value nulls_unequalValid Values nulls_unequalnulls_equalnulls_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 10.3.8, “InnoDB and MyISAM Index Statistics Collection”.
-
Command-Line Format --myisam-use-mmap[={OFF|ON}]System Variable myisam_use_mmapScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFUse memory mapping for reading and writing
MyISAMtables. mysql_native_password_proxy_usersCommand-Line Format --mysql-native-password-proxy-users[={OFF|ON}]Deprecated Yes System Variable mysql_native_password_proxy_usersScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable controls whether the
mysql_native_passwordbuilt-in authentication plugin (deprecated) supports proxy users. It has no effect unless thecheck_proxy_userssystem variable and themysql_native_passwordplugin are enabled. For information about user proxying, see Section 8.2.19, “Proxy Users”.-
Command-Line Format --named-pipe[={OFF|ON}]System Variable named_pipeScope Global Dynamic No SET_VARHint AppliesNo Platform Specific Windows Type Boolean Default Value OFF(Windows only.) Indicates whether the server supports connections over named pipes.
-
Command-Line Format --named-pipe-full-access-group=valueSystem Variable named_pipe_full_access_groupScope Global Dynamic No SET_VARHint AppliesNo Platform Specific Windows Type String Default Value empty stringValid Values empty stringvalid Windows local group name*everyone*(Windows only.) The access control granted to clients on the named pipe created by the MySQL server is set to the minimum necessary for successful communication when the
named_pipesystem variable is enabled to support named-pipe connections. Some MySQL client software can open named pipe connections without any additional configuration; however, other client software may still require full access to open a named pipe connection.This variable sets the name of a Windows local group whose members are granted sufficient access by the MySQL server to use named-pipe clients. The default value is an empty string, which means that no Windows user is granted full access to the named pipe.
A new Windows local group name (for example,
mysql_access_client_users) can be created in Windows and then used to replace the default value when access is absolutely necessary. In this case, limit the membership of the group to as few users as possible, removing users from the group when their client software is upgraded. A non-member of the group who attempts to open a connection to MySQL with the affected named-pipe client is denied access until a Windows administrator adds the user to the group. Newly added users must log out and log in again to join the group (required by Windows).Setting the value to
'*everyone*'provides a language-independent way of referring to the Everyone group on Windows. The Everyone group is not secure by default. -
Command-Line Format --net-buffer-length=#System Variable net_buffer_lengthScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 16384Minimum Value 1024Maximum Value 1048576Unit bytes Block Size 1024Each 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.The session value of this variable is read only.
-
Command-Line Format --net-read-timeout=#System Variable net_read_timeoutScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 30Minimum Value 1Maximum Value 31536000Unit seconds The number of seconds to wait for more data from a connection before aborting the read. 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 alsoreplica_net_timeout. -
Command-Line Format --net-retry-count=#System Variable net_retry_countScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 10Minimum Value 1Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295If 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.
-
Command-Line Format --net-write-timeout=#System Variable net_write_timeoutScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 60Minimum Value 1Maximum Value 31536000Unit seconds The number of seconds to wait for a block to be written to a connection before aborting the write. See also
net_read_timeout. -
Command-Line Format --ngram-token-size=#System Variable ngram_token_sizeScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 2Minimum Value 1Maximum Value 10Defines the n-gram token size for the n-gram full-text parser. The
ngram_token_sizeoption is read-only and can only be modified at startup. The default value is 2 (bigram). The maximum value is 10.For more information about how to configure this variable, see Section 14.9.8, “ngram Full-Text Parser”.
-
Command-Line Format --offline-mode[={OFF|ON}]System Variable offline_modeScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIn offline mode, the MySQL instance disconnects client users unless they have relevant privileges, and does not allow them to initiate new connections. Clients that are refused access receive an
ER_SERVER_OFFLINE_MODEerror.To put a server in offline mode, change the value of the
offline_modesystem variable fromOFFtoON. To resume normal operations, changeoffline_modefromONtoOFF. To control offline mode, an administrator account must have theSYSTEM_VARIABLES_ADMINprivilege and theCONNECTION_ADMINprivilege (or the deprecatedSUPERprivilege, which covers both these privileges).CONNECTION_ADMINis required, to prevent accidental lockout.Offline mode has these characteristics:
Connected client users who do not have the
CONNECTION_ADMINprivilege (or the deprecatedSUPERprivilege) are disconnected on the next request, with an appropriate error. Disconnection includes terminating running statements and releasing locks. Such clients also cannot initiate new connections, and receive an appropriate error.Connected client users who have the
CONNECTION_ADMINorSUPERprivilege are not disconnected, and can initiate new connections to manage the server.If the user that puts a server in offline mode does not have the
SYSTEM_USERprivilege, connected client users who have theSYSTEM_USERprivilege are also not disconnected. However, these users cannot initiate new connections to the server while it is in offline mode, unless they have theCONNECTION_ADMINorSUPERprivilege as well. It is only their existing connection that cannot be terminated, because theSYSTEM_USERprivilege is required to kill a session or statement that is executing with theSYSTEM_USERprivilege.Replication threads are permitted to keep applying data to the server.
-
Command-Line Format --old-alter-table[={OFF|ON}]System Variable old_alter_tableScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value 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 15.1.9, “ALTER TABLE Statement”.ALTER TABLE ... DROP PARTITIONwithold_alter_table=ONrebuilds the partitioned table and attempts to move data from the dropped partition to another partition with a compatiblePARTITION ... VALUESdefinition. Data that cannot be moved to another partition is deleted. In earlier releases,ALTER TABLE ... DROP PARTITIONwithold_alter_table=ONdeletes data stored in the partition and drops the partition. -
Command-Line Format --open-files-limit=#System Variable open_files_limitScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 5000, with possible adjustmentMinimum Value 0Maximum Value platform dependentThe number of file descriptors available to mysqld from the operating system:
At startup, mysqld reserves descriptors with
setrlimit(), using the value requested at by setting this variable directly or by using the--open-files-limitoption to mysqld_safe. If mysqld produces the errorToo many open files, try increasing theopen_files_limitvalue. Internally, the maximum value for this variable is the maximum unsigned integer value, but the actual maximum is platform dependent.At runtime, the value of
open_files_limitindicates the number of file descriptors actually permitted to mysqld by the operating system, which might differ from the value requested at startup. If the number of file descriptors requested during startup cannot be allocated, mysqld writes a warning to the error log.
The effective
open_files_limitvalue is based on the value specified at system startup (if any) and the values ofmax_connectionsandtable_open_cache, using these formulas:10 + max_connections + (table_open_cache * 2). Using the defaults for these variables yields 8161.On Windows only, 2048 (the value of the C Run-Time Library file descriptor maximum) is added to this number. This totals 10209, again using the default values for the indicated system variables.
max_connections * 5The operating system limit.
The server attempts to obtain the number of file descriptors using the maximum of those values, capped to the maximum unsigned integer value. If that many descriptors cannot be obtained, the server attempts to obtain as many as the system permits.
The effective value is 0 on systems where MySQL cannot change the number of open files.
On Unix, the value cannot be set greater than the value displayed by the ulimit -n command. On Linux systems using
systemd, the value cannot be set greater thanLimitNOFILE(this isDefaultLimitNOFILE, ifLimitNOFILEis not set); otherwise, on Linux, the value ofopen_files_limitcannot exceed ulimit -n. -
Command-Line Format --optimizer-prune-level=#System Variable optimizer_prune_levelScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 1Minimum Value 0Maximum Value 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 optimizer_search_depthScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 62Minimum Value 0Maximum Value 62The 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.
-
Command-Line Format --optimizer-switch=valueSystem Variable optimizer_switchScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Set Valid Values batched_key_access={on|off}block_nested_loop={on|off}condition_fanout_filter={on|off}derived_condition_pushdown={on|off}derived_merge={on|off}duplicateweedout={on|off}engine_condition_pushdown={on|off}firstmatch={on|off}hash_join={on|off}index_condition_pushdown={on|off}index_merge={on|off}index_merge_intersection={on|off}index_merge_sort_union={on|off}index_merge_union={on|off}loosescan={on|off}materialization={on|off}mrr={on|off}mrr_cost_based={on|off}prefer_ordering_index={on|off}semijoin={on|off}skip_scan={on|off}subquery_materialization_cost_based={on|off}subquery_to_derived={on|off}use_index_extensions={on|off}use_invisible_indexes={on|off}The
optimizer_switchsystem variable enables control over optimizer behavior. 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=on, engine_condition_pushdown=on,index_condition_pushdown=on, mrr=on,mrr_cost_based=on,block_nested_loop=on, batched_key_access=off,materialization=on,semijoin=on, loosescan=on,firstmatch=on,duplicateweedout=on, subquery_materialization_cost_based=on, use_index_extensions=on,condition_fanout_filter=on, derived_merge=on,use_invisible_indexes=off,skip_scan=on, hash_join=on,subquery_to_derived=off, prefer_ordering_index=on,hypergraph_optimizer=off, derived_condition_pushdown=on,hash_set_operations=on 1 row in set (0.00 sec)For more information about the syntax of this variable and the optimizer behaviors that it controls, see Section 10.9.2, “Switchable Optimizations”.
-
Command-Line Format --optimizer-trace=valueSystem Variable optimizer_traceScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String This variable controls optimizer tracing. For details, see Section 10.15, “Tracing the Optimizer”.
-
Command-Line Format --optimizer-trace-features=valueSystem Variable optimizer_trace_featuresScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String This variable enables or disables selected optimizer tracing features. For details, see Section 10.15, “Tracing the Optimizer”.
-
Command-Line Format --optimizer-trace-limit=#System Variable optimizer_trace_limitScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1Minimum Value 0Maximum Value 2147483647The maximum number of optimizer traces to display. For details, see Section 10.15, “Tracing the Optimizer”.
-
Command-Line Format --optimizer-trace-max-mem-size=#System Variable optimizer_trace_max_mem_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 1048576Minimum Value 0Maximum Value 4294967295Unit bytes The maximum cumulative size of stored optimizer traces. For details, see Section 10.15, “Tracing the Optimizer”.
-
Command-Line Format --optimizer-trace-offset=#System Variable optimizer_trace_offsetScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value -1Minimum Value -2147483647Maximum Value 2147483647The offset of optimizer traces to display. For details, see Section 10.15, “Tracing the Optimizer”.
performance_schema_xxxPerformance Schema system variables are listed in Section 29.15, “Performance Schema System Variables”. These variables may be used to configure Performance Schema operation.
-
Command-Line Format --parser-max-mem-size=#System Variable parser_max_mem_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value (64-bit platforms) 18446744073709551615Default Value (32-bit platforms) 4294967295Minimum Value 10000000Maximum Value (64-bit platforms) 18446744073709551615Maximum Value (32-bit platforms) 4294967295Unit bytes The maximum amount of memory available to the parser. The default value places no limit on memory available. The value can be reduced to protect against out-of-memory situations caused by parsing long or complex SQL statements.
-
Command-Line Format --partial-revokes[={OFF|ON}]System Variable partial_revokesScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFF(if partial revokes do not exist)ON(if partial revokes exist)Enabling this variable makes it possible to revoke privileges partially. Specifically, for users who have privileges at the global level,
partial_revokesenables privileges for specific schemas to be revoked while leaving the privileges in place for other schemas. For example, a user who has the globalUPDATEprivilege can be restricted from exercising this privilege on themysqlsystem schema. (Or, stated another way, the user is enabled to exercise theUPDATEprivilege on all schemas except themysqlschema.) In this sense, the user's globalUPDATEprivilege is partially revoked.Once enabled,
partial_revokescannot be disabled if any account has privilege restrictions. If any such account exists, disablingpartial_revokesfails:For attempts to disable
partial_revokesat startup, the server logs an error message and enablespartial_revokes.For attempts to disable
partial_revokesat runtime, an error occurs and thepartial_revokesvalue remains unchanged.
To disable
partial_revokesin this case, first modify each account that has partially revoked privileges, either by re-granting the privileges or by removing the account.NoteIn privilege assignments, enabling
partial_revokescauses MySQL to interpret occurrences of unescaped_and%SQL wildcard characters in schema names as literal characters, just as if they had been escaped as\_and\%. Because this changes how MySQL interprets privileges, it may be advisable to avoid unescaped wildcard characters in privilege assignments for installations wherepartial_revokesmay be enabled.In addition, use of
_and%as wildcard characters in grants is deprecated, and you should expect support for them to be removed in a future version of MySQL.For more information, including instructions for removing partial revokes, see Section 8.2.12, “Privilege Restriction Using Partial Revokes”.
-
Command-Line Format --password-history=#System Variable password_historyScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 4294967295This variable defines the global policy for controlling reuse of previous passwords based on required minimum number of password changes. For an account password used previously, this variable indicates the number of subsequent account password changes that must occur before the password can be reused. If the value is 0 (the default), there is no reuse restriction based on number of password changes.
Changes to this variable apply immediately to all accounts defined with the
PASSWORD HISTORY DEFAULToption.The global number-of-changes password reuse policy can be overridden as desired for individual accounts using the
PASSWORD HISTORYoption of theCREATE USERandALTER USERstatements. See Section 8.2.15, “Password Management”. -
Command-Line Format --password-require-current[={OFF|ON}]System Variable password_require_currentScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable defines the global policy for controlling whether attempts to change an account password must specify the current password to be replaced.
Changes to this variable apply immediately to all accounts defined with the
PASSWORD REQUIRE CURRENT DEFAULToption.The global verification-required policy can be overridden as desired for individual accounts using the
PASSWORD REQUIREoption of theCREATE USERandALTER USERstatements. See Section 8.2.15, “Password Management”. -
Command-Line Format --password-reuse-interval=#System Variable password_reuse_intervalScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 4294967295Unit days This variable defines the global policy for controlling reuse of previous passwords based on time elapsed. For an account password used previously, this variable indicates the number of days that must pass before the password can be reused. If the value is 0 (the default), there is no reuse restriction based on time elapsed.
Changes to this variable apply immediately to all accounts defined with the
PASSWORD REUSE INTERVAL DEFAULToption.The global time-elapsed password reuse policy can be overridden as desired for individual accounts using the
PASSWORD REUSE INTERVALoption of theCREATE USERandALTER USERstatements. See Section 8.2.15, “Password Management”. -
Command-Line Format --persisted-globals-load[={OFF|ON}]System Variable persisted_globals_loadScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONWhether to load persisted configuration settings from the
mysqld-auto.cnffile in the data directory. The server normally processes this file at startup after all other option files (see Section 6.2.2.2, “Using Option Files”). Disablingpersisted_globals_loadcauses the server startup sequence to skipmysqld-auto.cnf.To modify the contents of
mysqld-auto.cnf, use theSET PERSIST,SET PERSIST_ONLY, andRESET PERSISTstatements. See Section 7.1.9.3, “Persisted System Variables”. persist_only_admin_x509_subjectCommand-Line Format --persist-only-admin-x509-subject=stringSystem Variable persist_only_admin_x509_subjectScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value empty stringSET PERSISTandSET PERSIST_ONLYenable system variables to be persisted to themysqld-auto.cnfoption file in the data directory (see Section 15.7.6.1, “SET Syntax for Variable Assignment”). Persisting system variables enables runtime configuration changes that affect subsequent server restarts, which is convenient for remote administration not requiring direct access to MySQL server host option files. However, some system variables are nonpersistible or can be persisted only under certain restrictive conditions.The
persist_only_admin_x509_subjectsystem variable specifies the SSL certificate X.509 Subject value that users must have to be able to persist system variables that are persist-restricted. The default value is the empty string, which disables the Subject check so that persist-restricted system variables cannot be persisted by any user.If
persist_only_admin_x509_subjectis nonempty, users who connect to the server using an encrypted connection and supply an SSL certificate with the designated Subject value then can useSET PERSIST_ONLYto persist persist-restricted system variables. For information about persist-restricted system variables and instructions for configuring MySQL to enablepersist_only_admin_x509_subject, see Section 7.1.9.4, “Nonpersistible and Persist-Restricted System Variables”.persist_sensitive_variables_in_plaintextCommand-Line Format --persist_sensitive_variables_in_plaintext[={OFF|ON}]System Variable persist_sensitive_variables_in_plaintextScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONpersist_sensitive_variables_in_plaintextcontrols whether the server is permitted to store the values of sensitive system variables in an unencrypted format, if keyring component support is not available at the time whenSET PERSISTis used to set the value of the system variable. It also controls whether or not the server can start if the encrypted values cannot be decrypted. Note that keyring plugins do not support secure storage of sensitive system variables; a keyring component (see Section 8.4.4, “The MySQL Keyring”) must be enabled on the MySQL Server instance to support secure storage.The default setting,
ON, encrypts the values if keyring component support is available, and persists them unencrypted (with a warning) if it is not. The next time any persisted system variable is set, if keyring support is available at that time, the server encrypts the values of any unencrypted sensitive system variables. TheONsetting also allows the server to start if encrypted system variable values cannot be decrypted, in which case a warning is issued and the default values for the system variables are used. In that situation, their values cannot be changed until they can be decrypted.The most secure setting,
OFF, means sensitive system variable values cannot be persisted if keyring component support is unavailable. TheOFFsetting also means the server does not start if encrypted system variable values cannot be decrypted.For more information, see Persisting Sensitive System Variables.
-
Command-Line Format --pid-file=file_nameSystem Variable pid_fileScope Global Dynamic No SET_VARHint AppliesNo Type File name The path name of the file in which the server writes its process ID. The server creates the file in the data directory unless an absolute path name is given to specify a different directory. If you specify this variable, you must specify a value. If you do not specify this variable, MySQL uses a default value of
, wherehost_name.pidhost_nameis the name of the host machine.The process ID file is used by other programs such as mysqld_safe to determine the server's process ID. On Windows, this variable also affects the default error log file name. See Section 7.4.2, “The Error Log”.
-
Command-Line Format --plugin-dir=dir_nameSystem Variable plugin_dirScope Global Dynamic No SET_VARHint AppliesNo Type Directory name Default Value BASEDIR/lib/pluginThe path name of the plugin directory.
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 settingsecure_file_privto a directory whereSELECTwrites can be made safely. -
Command-Line Format --port=port_numSystem Variable portScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 3306Minimum Value 0Maximum 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 preload_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 32768Minimum Value 1024Maximum Value 1073741824Unit bytes The size of the buffer that is allocated when preloading indexes.
Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --print-identified-with-as-hex[={OFF|ON}]System Variable print_identified_with_as_hexScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFPassword hash values displayed in the
IDENTIFIED WITHclause of output fromSHOW CREATE USERmay contain unprintable characters that have adverse effects on terminal displays and in other environments. Enablingprint_identified_with_as_hexcausesSHOW CREATE USERto display such hash values as hexadecimal strings rather than as regular string literals. Hash values that do not contain unprintable characters still display as regular string literals, even with this variable enabled. 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 15.7.7.33, “SHOW PROFILES Statement”.This variable is deprecated; expect it to be removed in a future MySQL release.
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 15.7.7.33, “SHOW PROFILES Statement”.This variable is deprecated; expect it to be removed in a future MySQL release.
protocol_compression_algorithmsCommand-Line Format --protocol-compression-algorithms=valueSystem Variable protocol_compression_algorithmsScope Global Dynamic Yes SET_VARHint AppliesNo Type Set Default Value zlib,zstd,uncompressedValid Values zlibzstduncompressedThe compression algorithms that the server permits for incoming connections. These include connections by client programs and by servers participating in source/replica replication or Group Replication. Compression does not apply to connections for
FEDERATEDtables.protocol_compression_algorithmsdoes not control connection compression for X Protocol. See Section 22.5.5, “Connection Compression with X Plugin” for information on how this operates.The variable value is a list of one or more comma-separated compression algorithm names, in any order, chosen from the following items (not case-sensitive):
zlib: Permit connections that use thezlibcompression algorithm.zstd: Permit connections that use thezstdcompression algorithm.uncompressed: Permit uncompressed connections. If this algorithm name is not included in theprotocol_compression_algorithmsvalue, the server does not permit uncompressed connections. It permits only compressed connections that use whichever other algorithms are specified in the value, and there is no fallback to uncompressed connections.
The default value of
zlib,zstd,uncompressedindicates that the server permits all compression algorithms.For more information, see Section 6.2.8, “Connection Compression Control”.
-
System Variable protocol_versionScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 10Minimum Value 0Maximum Value 4294967295The version of the client/server protocol used by the MySQL server.
-
System Variable proxy_userScope Session Dynamic No SET_VARHint AppliesNo Type String If the current client is a proxy for another user, this variable is the proxy user account name. Otherwise, this variable is
NULL. See Section 8.2.19, “Proxy Users”. -
System Variable pseudo_replica_modeScope Session Dynamic Yes SET_VARHint AppliesNo Type Boolean pseudo_replica_modeis for internal server use. It assists with the correct handling of transactions that originated on older or newer servers than the server currently processing them. mysqlbinlog sets the value ofpseudo_replica_modeto true before executing any SQL statements.Setting the session value of
pseudo_replica_modeis a restricted operation. The session user must have either theREPLICATION_APPLIERprivilege (see Section 19.3.3, “Replication Privilege Checks”), or privileges sufficient to set restricted session variables (see Section 7.1.9.1, “System Variable Privileges”). However, note that the variable is not intended for users to set; it is set automatically by the replication infrastructure.pseudo_replica_modehas the following effects on the handling of prepared XA transactions, which can be attached to or detached from the handling session (by default, the session that issuesXA START):If true, and the handling session has executed an internal-use
BINLOGstatement, XA transactions are automatically detached from the session as soon as the first part of the transaction up toXA PREPAREfinishes, so they can be committed or rolled back by any session that has theXA_RECOVER_ADMINprivilege.If false, XA transactions remain attached to the handling session as long as that session is alive, during which time no other session can commit the transaction. The prepared transaction is only detached if the session disconnects or the server restarts.
pseudo_replica_modehas the following effects on theoriginal_commit_timestampreplication delay timestamp and theoriginal_server_versionsystem variable:If true, transactions that do not explicitly set
original_commit_timestampororiginal_server_versionare assumed to originate on another, unknown server, so the value 0, meaning unknown, is assigned to both the timestamp and the system variable.If false, transactions that do not explicitly set
original_commit_timestampororiginal_server_versionare assumed to originate on the current server, so the current timestamp and the current server's version are assigned to the timestamp and the system variable.
pseudo_replica_modehas the following effects on the handling of a statement that sets one or more unsupported (removed or unknown) SQL modes:If true, the server ignores the unsupported mode and raises a warning.
If false, the server rejects the statement with
ER_UNSUPPORTED_SQL_MODE.
-
Deprecated Yes System Variable pseudo_slave_modeScope Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Deprecated alias for
pseudo_replica_mode. -
System Variable pseudo_thread_idScope Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 2147483647Minimum Value 0Maximum Value 2147483647This variable is for internal server use.
WarningChanging the session value of the
pseudo_thread_idsystem variable changes the value returned by theCONNECTION_ID()function.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --query-alloc-block-size=#System Variable query_alloc_block_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8192Minimum Value 1024Maximum Value 4294966272Unit bytes Block Size 1024The allocation size in bytes 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.
The block size for the byte number is 1024. A value that is not an exact multiple of the block size is rounded down to the next lower multiple of the block size by MySQL Server before storing the value for the system variable. The parser allows values up to the maximum unsigned integer value for the platform (4294967295 or 232−1 for a 32-bit system, 18446744073709551615 or 264−1 for a 64-bit system) but the actual maximum is a block size lower.
-
Command-Line Format --query-prealloc-size=#Deprecated Yes System Variable query_prealloc_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8192Minimum Value 8192Maximum Value (64-bit platforms) 18446744073709550592Maximum Value (32-bit platforms) 4294966272Unit bytes Block Size 1024query_prealloc_sizeis deprecated, and setting it has no effect; you should expect its removal in a future release of MySQL. -
System Variable rand_seed1Scope Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value N/AMinimum Value 0Maximum Value 4294967295The
rand_seed1andrand_seed2variables exist as session variables only, and can be set but not read. 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 source passes two values to the replica, where they are used to seed the random number generator. The replica uses these values to set the session variablesrand_seed1andrand_seed2so thatRAND()on the replica generates the same value as on the source. See the description for
rand_seed1.-
Command-Line Format --range-alloc-block-size=#System Variable range_alloc_block_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 4096Minimum Value 4096Maximum Value (64-bit platforms) 18446744073709550592Maximum Value 4294966272Unit bytes Block Size 1024The size in bytes of blocks that are allocated when doing range optimization.
The block size for the byte number is 1024. A value that is not an exact multiple of the block size is rounded down to the next lower multiple of the block size by MySQL Server before storing the value for the system variable. The parser allows values up to the maximum unsigned integer value for the platform (4294967295 or 232−1 for a 32-bit system, 18446744073709551615 or 264−1 for a 64-bit system) but the actual maximum is a block size lower.
-
Command-Line Format --range-optimizer-max-mem-size=#System Variable range_optimizer_max_mem_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 8388608Minimum Value 0Maximum Value 18446744073709551615Unit bytes The limit on memory consumption for the range optimizer. A value of 0 means “no limit.” If an execution plan considered by the optimizer uses the range access method but the optimizer estimates that the amount of memory needed for this method would exceed the limit, it abandons the plan and considers other plans. For more information, see Limiting Memory Use for Range Optimization.
-
System Variable rbr_exec_modeScope Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value STRICTValid Values STRICTIDEMPOTENTFor internal use by mysqlbinlog. This variable switches the server between
IDEMPOTENTmode andSTRICTmode.IDEMPOTENTmode causes suppression of duplicate-key and no-key-found errors inBINLOGstatements generated by mysqlbinlog. This mode is useful when replaying a row-based binary log on a server that causes conflicts with existing data. mysqlbinlog sets this mode when you specify the--idempotentoption by writing the following to the output:SET SESSION RBR_EXEC_MODE=IDEMPOTENT; -
Command-Line Format --read-buffer-size=#System Variable read_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 131072Minimum Value 8192Maximum Value 2147479552Unit bytes Block Size 4096Each 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 is rounded down to the nearest multiple of 4KB.This option is also used in the following context for all other storage engines with the exception of
InnoDB: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.
read_buffer_sizeis also used in one other storage engine-specific way: to determine the memory block size forMEMORYtables.select_into_buffer_sizeis used for the I/O cache buffer forSELECT INTO DUMPFILEandSELECT INTO OUTFILEstatements. (read_buffer_sizeis used for the I/O cache buffer size in all other cases.)For more information about memory use during different operations, see Section 10.12.3.1, “How MySQL Uses Memory”.
-
Command-Line Format --read-only[={OFF|ON}]System Variable read_onlyScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIf the
read_onlysystem variable is enabled, the server permits no client updates except from users who have theCONNECTION_ADMINprivilege (or the deprecatedSUPERprivilege). This variable is disabled by default.The server also supports a
super_read_onlysystem variable (disabled by default), which has these effects:If
super_read_onlyis enabled, the server prohibits client updates, even from users who have theCONNECTION_ADMINorSUPERprivilege.Setting
super_read_onlytoONimplicitly forcesread_onlytoON.Setting
read_onlytoOFFimplicitly forcessuper_read_onlytoOFF.
When
read_onlyis enabled and whensuper_read_onlyis enabled, the server still permits these operations:Updates performed by replication threads, if the server is a replica. In replication setups, it can be useful to enable
read_onlyon replica servers to ensure that replicas accept updates only from the source server and not from clients.Writes to the system table
mysql.gtid_executed, which stores GTIDs for executed transactions that are not present in the current binary log file.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 replicas can be performed with mysqlcheck--all-databases--analyze.Use of
FLUSH STATUSstatements, which are always written to the binary log.Operations on
TEMPORARYtables.Inserts into the log tables (
mysql.general_logandmysql.slow_log); see Section 7.4.1, “Selecting General Query Log and Slow Query Log Output Destinations”.Updates to Performance Schema tables, such as
UPDATEorTRUNCATE TABLEoperations.
Changes to
read_onlyon a replication source server are not replicated to replica servers. The value can be set on a replica independent of the setting on the source.The following conditions apply to attempts to enable
read_only(including implicit attempts resulting from enablingsuper_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 have any ongoing statement, active
LOCK TABLES WRITE, or ongoing commit, until the locks are released and the statements and transactions end. While the attempt to enableread_onlyis pending, requests by other clients for table locks or to begin transactions also block untilread_onlyhas been set.The attempt blocks if there are active transactions that hold metadata locks, until those transactions end.
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 read_rnd_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 262144Minimum Value 1Maximum Value 2147483647Unit bytes This variable is used for reads from
MyISAMtables, and, for any storage engine, for Multi-Range Read optimization.When 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 10.2.1.16, “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.For more information about memory use during different operations, see Section 10.12.3.1, “How MySQL Uses Memory”. For information about Multi-Range Read optimization, see Section 10.2.1.11, “Multi-Range Read Optimization”.
-
Command-Line Format --regexp-stack-limit=#System Variable regexp_stack_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8000000Minimum Value 0Maximum Value 2147483647Unit bytes The maximum available memory in bytes for the internal stack used for regular expression matching operations performed by
REGEXP_LIKE()and similar functions (see Section 14.8.2, “Regular Expressions”). -
Command-Line Format --regexp-time-limit=#System Variable regexp_time_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 32Minimum Value 0Maximum Value 2147483647The time limit for regular expression matching operations performed by
REGEXP_LIKE()and similar functions (see Section 14.8.2, “Regular Expressions”). This limit is expressed as the maximum permitted number of steps performed by the match engine, and thus affects execution time only indirectly. Typically, it is on the order of milliseconds. -
System Variable require_row_formatScope Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable is for internal server use by replication and mysqlbinlog. It restricts DML events executed in the session to events encoded in row-based binary logging format only, and temporary tables cannot be created. Queries that do not respect the restrictions fail.
Setting the session value of this system variable to
ONrequires no privileges. Setting the session value of this system variable toOFFis a restricted operation, and the session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”. -
Command-Line Format --require-secure-transport[={OFF|ON}]System Variable require_secure_transportScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFWhether client connections to the server are required to use some form of secure transport. When this variable is enabled, the server permits only TCP/IP connections encrypted using TLS/SSL, or connections that use a socket file (on Unix) or shared memory (on Windows). The server rejects nonsecure connection attempts, which fail with an
ER_SECURE_TRANSPORT_REQUIREDerror.This capability supplements per-account SSL requirements, which take precedence. For example, if an account is defined with
REQUIRE SSL, enablingrequire_secure_transportdoes not make it possible to use the account to connect using a Unix socket file.It is possible for a server to have no secure transports available. For example, a server on Windows supports no secure transports if started without specifying any SSL certificate or key files and with the
shared_memorysystem variable disabled. Under these conditions, attempts to enablerequire_secure_transportat startup cause the server to write a message to the error log and exit. Attempts to enable the variable at runtime fail with anER_NO_SECURE_TRANSPORTS_CONFIGUREDerror.All replication group members should have the same value for this variable; otherwise, some members may not be able to join.
restrict_fk_on_non_standard_keyCommand-Line Format --restrict-fk-on-non-standard-keyDeprecated Yes System Variable restrict_fk_on_non_standard_keyScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONThis variable, when
ON(the default), prevents the use of non-unique keys or partial keys as foreign keys. To allow such keys to be used as foreign keys in the current session, useSET @@session.restrict_fk_on_non_standard_key=OFF; to allow them to be used globally, set the global variable or start the server with--skip-restrict-fk-on-non-standard-key.Using non-unique or partial keys as foreign keys in a
CREATE TABLEorALTER TABLEstatement is deprecated, and you should expect support for it to be removed in a future version of MySQL. Whenrestrict_fk_on_non_standard_keyisON, attempts to do so are rejected withER_FK_NO_INDEX_PARENT; when it isOFF, this usage is permitted but still raisesER_WARN_DEPRECATED_NON_STANDARD_KEYas a warning.restrict_fk_on_non_standard_keyis deprecated, and subject to removal in a future version of MySQL. Setting it raises a deprecation warning.Implication for MySQL Replication. When a foreign key is created on a nonstandard key on the primary because
restrict_fk_on_non_standard_keyisOFF, the statement succeeds on the replica regardless of any setting on the replica for this variable.-
System Variable resultset_metadataScope Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value FULLValid Values FULLNONEFor connections for which metadata transfer is optional, the client sets the
resultset_metadatasystem variable to control whether the server returns result set metadata. Permitted values areFULL(return all metadata; this is the default) andNONE(return no metadata).For connections that are not metadata-optional, setting
resultset_metadatatoNONEproduces an error.For details about managing result set metadata transfer, see Optional Result Set Metadata.
secondary_engine_cost_thresholdFor use with MySQL HeatWave only. See System Variables, for more information.
-
Command-Line Format --schema-definition-cache=#System Variable schema_definition_cacheScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 256Minimum Value 256Maximum Value 524288Defines a limit for the number of schema definition objects, both used and unused, that can be kept in the dictionary object cache.
Unused schema definition objects are only kept in the dictionary object cache when the number in use is less than the capacity defined by
schema_definition_cache.A setting of
0means that schema definition objects are only kept in the dictionary object cache while they are in use.For more information, see Section 16.4, “Dictionary Object Cache”.
-
Command-Line Format --secure-file-priv=dir_nameSystem Variable secure_file_privScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value platform specificValid Values empty stringdirnameNULLThis 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. These operations are permitted only to users who have theFILEprivilege.secure_file_privmay be set as follows:If empty, the variable has no effect. This is not a secure setting.
If set to the name of a directory, the server limits import and export operations to work only with files in that directory. The directory must exist; the server does not create it.
If set to
NULL, the server disables import and export operations.
The default value is platform specific and depends on the value of the
INSTALL_LAYOUTCMake option, as shown in the following table. To specify the defaultsecure_file_privvalue explicitly if you are building from source, use theINSTALL_SECURE_FILE_PRIVDIRCMake option.INSTALL_LAYOUTValueDefault secure_file_privValueSTANDALONEempty DEB,RPM,SVR4/var/lib/mysql-filesOtherwise mysql-filesunder theCMAKE_INSTALL_PREFIXvalueThe server checks the value of
secure_file_privat startup and writes a warning to the error log if the value is insecure. A non-NULLvalue is considered insecure if it is empty, or the value is the data directory or a subdirectory of it, or a directory that is accessible by all users. Ifsecure_file_privis set to a nonexistent path, the server writes an error message to the error log and exits. -
Command-Line Format --select-into-buffer-size=#System Variable select_into_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 131072Minimum Value 8192Maximum Value 2147479552Unit bytes Block Size 4096When using
SELECT INTO OUTFILEorSELECT INTO DUMPFILEto dump data into one or more files for backup creation, data migration, or other purposes, writes can often be buffered and then trigger a large burst of write I/O activity to the disk or other storage device and stall other queries that are more sensitive to latency. You can use this variable to control the size of the buffer used to write data to the storage device to determine when buffer synchronization should occur, and thus to prevent write stalls of the kind just described from occurring.select_into_buffer_sizeoverrides any value set forread_buffer_size. (select_into_buffer_sizeandread_buffer_sizehave the same default, maximum, and minimum values.) You can also useselect_into_disk_sync_delayto set a timeout to be observed afterwards, each time synchronization takes place.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --select-into-disk-sync={ON|OFF}System Variable select_into_disk_syncScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFValid Values OFFONWhen set on
ON, enables buffer synchronization of writes to an output file by a long-runningSELECT INTO OUTFILEorSELECT INTO DUMPFILEstatement usingselect_into_buffer_size. -
Command-Line Format --select-into-disk-sync-delay=#System Variable select_into_disk_sync_delayScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 0Minimum Value 0Maximum Value 31536000Unit milliseconds When buffer synchronization of writes to an output file by a long-running
SELECT INTO OUTFILEorSELECT INTO DUMPFILEstatement is enabled byselect_into_disk_sync, this variable sets an optional delay (in milliseconds) following synchronization.0(the default) means no delay.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --session-track-gtids=valueSystem Variable session_track_gtidsScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value OFFValid Values OFFOWN_GTIDALL_GTIDSControls whether the server returns GTIDs to the client, enabling the client to use them to track the server state. Depending on the variable value, at the end of executing each transaction, the server’s GTIDs are captured and returned to the client as part of the acknowledgement. The possible values for
session_track_gtidsare as follows:OFF: The server does not return GTIDs to the client. This is the default.OWN_GTID: The server returns the GTIDs for all transactions that were successfully committed by this client in its current session since the last acknowledgement. Typically, this is the single GTID for the last transaction committed, but if a single client request resulted in multiple transactions, the server returns a GTID set containing all the relevant GTIDs.ALL_GTIDS: The server returns the global value of itsgtid_executedsystem variable, which it reads at a point after the transaction is successfully committed. As well as the GTID for the transaction just committed, this GTID set includes all transactions committed on the server by any client, and can include transactions committed after the point when the transaction currently being acknowledged was committed.
session_track_gtidscannot be set within transactional context.For more information about session state tracking, see Section 7.1.18, “Server Tracking of Client Session State”.
-
Command-Line Format --session-track-schema[={OFF|ON}]System Variable session_track_schemaScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONControls whether the server tracks when the default schema (database) is set within the current session and notifies the client to make the schema name available.
If the schema name tracker is enabled, name notification occurs each time the default schema is set, even if the new schema name is the same as the old.
For more information about session state tracking, see Section 7.1.18, “Server Tracking of Client Session State”.
-
Command-Line Format --session-track-state-change[={OFF|ON}]System Variable session_track_state_changeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFControls whether the server tracks changes to the state of the current session and notifies the client when state changes occur. Changes can be reported for these attributes of client session state:
The default schema (database).
Session-specific values for system variables.
User-defined variables.
Temporary tables.
Prepared statements.
If the session state tracker is enabled, notification occurs for each change that involves tracked session attributes, even if the new attribute values are the same as the old. For example, setting a user-defined variable to its current value results in a notification.
The
session_track_state_changevariable controls only notification of when changes occur, not what the changes are. For example, state-change notifications occur when the default schema is set or tracked session system variables are assigned, but the notification does not include the schema name or variable values. To receive notification of the schema name or session system variable values, use thesession_track_schemaorsession_track_system_variablessystem variable, respectively.NoteAssigning a value to
session_track_state_changeitself is not considered a state change and is not reported as such. However, if its name listed in the value ofsession_track_system_variables, any assignments to it do result in notification of the new value.For more information about session state tracking, see Section 7.1.18, “Server Tracking of Client Session State”.
session_track_system_variablesCommand-Line Format --session-track-system-variables=#System Variable session_track_system_variablesScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type String Default Value time_zone, autocommit, character_set_client, character_set_results, character_set_connectionControls whether the server tracks assignments to session system variables and notifies the client of the name and value of each assigned variable. The variable value is a comma-separated list of variables for which to track assignments. By default, notification is enabled for
time_zone,autocommit,character_set_client,character_set_results, andcharacter_set_connection. (The latter three variables are those affected bySET NAMES.)To enable display of the Statement ID for each statement processed, use the
statement_idvariable. For example:mysql> SET @@SESSION.session_track_system_variables='statement_id' mysql> SELECT 1; +---+ | 1 | +---+ | 1 | +---+ 1 row in set (0.0006 sec) Statement ID: 603835The special value
*(asterisk) causes the server to track assignments to all session variables. If given, this value must be specified by itself without specific system variable names. This value also enables display of the Statement ID for each successful statement processed.To disable notification of session variable assignments, set
session_track_system_variablesto the empty string.If session system variable tracking is enabled, notification occurs for all assignments to tracked session variables, even if the new values are the same as the old.
For more information about session state tracking, see Section 7.1.18, “Server Tracking of Client Session State”.
session_track_transaction_infoCommand-Line Format --session-track-transaction-info=valueSystem Variable session_track_transaction_infoScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value OFFValid Values OFFSTATECHARACTERISTICSControls whether the server tracks the state and characteristics of transactions within the current session and notifies the client to make this information available. These
session_track_transaction_infovalues are permitted:OFF: Disable transaction state tracking. This is the default.STATE: Enable transaction state tracking without characteristics tracking. State tracking enables the client to determine whether a transaction is in progress and whether it could be moved to a different session without being rolled back.CHARACTERISTICS: Enable transaction state tracking, including characteristics tracking. Characteristics tracking enables the client to determine how to restart a transaction in another session so that it has the same characteristics as in the original session. The following characteristics are relevant for this purpose:ISOLATION LEVEL READ ONLY READ WRITE WITH CONSISTENT SNAPSHOT
For a client to safely relocate a transaction to another session, it must track not only transaction state but also transaction characteristics. In addition, the client must track the
transaction_isolationandtransaction_read_onlysystem variables to correctly determine the session defaults. (To track these variables, list them in the value of thesession_track_system_variablessystem variable.)For more information about session state tracking, see Section 7.1.18, “Server Tracking of Client Session State”.
-
Command-Line Format --set-operations-buffer-size=#System Variable set_operations_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 256KMinimum Value 16KMaximum Value 1 GBUnit bytes Block Size 128Sets the buffer size for
INTERSECTandEXCEPToperations that use hash tables when thehash_set_operationsoptimizer switch isON. In general, increasing the size of this buffer improves performance of these operations when the hashing optimization is enabled. sha256_password_auto_generate_rsa_keysCommand-Line Format --sha256-password-auto-generate-rsa-keys[={OFF|ON}]Deprecated Yes System Variable sha256_password_auto_generate_rsa_keysScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value ONThe server uses this variable to determine whether to autogenerate RSA private/public key-pair files in the data directory if they do not already exist.
At startup, the server automatically generates RSA private/public key-pair files in the data directory if all of these conditions are true: The
sha256_password_auto_generate_rsa_keysorcaching_sha2_password_auto_generate_rsa_keyssystem variable is enabled; no RSA options are specified; the RSA files are missing from the data directory. These key-pair files enable secure password exchange using RSA over unencrypted connections for accounts authenticated by thesha256_password(deprecated) orcaching_sha2_passwordplugin; see Section 8.4.1.3, “SHA-256 Pluggable Authentication”, and Section 8.4.1.2, “Caching SHA-2 Pluggable Authentication”.For more information about RSA file autogeneration, including file names and characteristics, see Section 8.3.3.1, “Creating SSL and RSA Certificates and Keys using MySQL”
The
auto_generate_certssystem variable is related but controls autogeneration of SSL certificate and key files needed for secure connections using SSL.sha256_password_private_key_pathCommand-Line Format --sha256-password-private-key-path=file_nameDeprecated Yes System Variable sha256_password_private_key_pathScope Global Dynamic No SET_VARHint AppliesNo Type File name Default Value private_key.pemThe value of this variable is the path name of the RSA private key file for the
sha256_password(deprecated) authentication plugin. If the file is named as a relative path, it is interpreted relative to the server data directory. The file must be in PEM format.ImportantBecause this file stores a private key, its access mode should be restricted so that only the MySQL server can read it.
For information about
sha256_password, see Section 8.4.1.3, “SHA-256 Pluggable Authentication”.-
Command-Line Format --sha256-password-proxy-users[={OFF|ON}]Deprecated Yes System Variable sha256_password_proxy_usersScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable controls whether the
sha256_password(deprecated) built-in authentication plugin supports proxy users. It has no effect unless thecheck_proxy_userssystem variable is enabled. For information about user proxying, see Section 8.2.19, “Proxy Users”. sha256_password_public_key_pathCommand-Line Format --sha256-password-public-key-path=file_nameDeprecated Yes System Variable sha256_password_public_key_pathScope Global Dynamic No SET_VARHint AppliesNo Type File name Default Value public_key.pemThe value of this variable is the path name of the RSA public key file for the
sha256_password(deprecated) authentication plugin. If the file is named as a relative path, it is interpreted relative to the server data directory. The file must be in PEM format. Because this file stores a public key, copies can be freely distributed to client users. (Clients that explicitly specify a public key when connecting to the server using RSA password encryption must use the same public key as that used by the server.)For information about
sha256_password(deprecated), including information about how clients specify the RSA public key, see Section 8.4.1.3, “SHA-256 Pluggable Authentication”.-
Command-Line Format --shared-memory[={OFF|ON}]System Variable shared_memoryScope Global Dynamic No SET_VARHint AppliesNo Platform Specific Windows Type Boolean Default Value OFF(Windows only.) Whether the server permits shared-memory connections.
-
Command-Line Format --shared-memory-base-name=nameSystem Variable shared_memory_base_nameScope Global Dynamic No SET_VARHint AppliesNo Platform Specific Windows Type String Default Value 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.This variable applies only if the server is started with the
shared_memorysystem variable enabled to support shared-memory connections. show_create_table_skip_secondary_engineFor use with MySQL HeatWave only. See System Variables, for more information.
-
Command-Line Format --show-create-table-verbosity[={OFF|ON}]System Variable show_create_table_verbosityScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFSHOW CREATE TABLEnormally does not show theROW_FORMATtable option if the row format is the default format. Enabling this variable causesSHOW CREATE TABLEto displayROW_FORMATregardless of whether it is the default format. show_gipk_in_create_table_and_information_schemaCommand-Line Format --show-gipk-in-create-table-and-information-schema[={OFF|ON}]System Variable show_gipk_in_create_table_and_information_schemaScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONWhether generated invisible primary keys are visible in the output of
SHOWstatements and in Information Schema tables. When this variable is set toOFF, such keys are not shown.This variable is not replicated.
For more information, see Section 15.1.20.11, “Generated Invisible Primary Keys”.
-
Command-Line Format --skip-external-locking[={OFF|ON}]System Variable skip_external_lockingScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value 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 10.11.5, “External Locking”. -
Command-Line Format --skip-name-resolve[={OFF|ON}]System Variable skip_name_resolveScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFWhether to resolve host names when checking client connections. If this variable is
OFF, 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. See Section 7.1.12.3, “DNS Lookups and the Host Cache”.Depending on the network configuration of your system and the
Hostvalues for your accounts, clients may need to connect using an explicit--hostoption, such as--host=127.0.0.1or--host=::1.An attempt to connect to the host
127.0.0.1normally resolves to thelocalhostaccount. However, this fails if the server is run withskip_name_resolveenabled. If you plan to do that, make sure an account exists that can accept a connection. For example, to be able to connect asrootusing--host=127.0.0.1or--host=::1, create these accounts:CREATE USER 'root'@'127.0.0.1' IDENTIFIED BY 'root-password'; CREATE USER 'root'@'::1' IDENTIFIED BY 'root-password'; -
Command-Line Format --skip-networking[={OFF|ON}]System Variable skip_networkingScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable controls whether the server permits TCP/IP connections. By default, it is disabled (permit TCP connections). If enabled, the server permits only local (non-TCP/IP) connections and all interaction with mysqld must be made using named pipes or shared memory (on Windows) or Unix socket files (on Unix). This option is highly recommended for systems where only local clients are permitted. See Section 7.1.12.3, “DNS Lookups and the Host Cache”.
Because starting the server with
--skip-grant-tablesdisables authentication checks, the server also disables remote connections in that case by enablingskip_networking. -
Command-Line Format --skip-show-databaseSystem Variable skip_show_databaseScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFThis 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.CautionBecause any static global privilege is considered a privilege for all databases, any static global privilege enables a user to see all database names with
SHOW DATABASESor by examining theSCHEMATAtable ofINFORMATION_SCHEMA, except databases that have been restricted at the database level by partial revokes. -
Command-Line Format --slow-launch-time=#System Variable slow_launch_timeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 2Minimum Value 0Maximum Value 31536000Unit seconds If creating a thread takes longer than this many seconds, the server increments the
Slow_launch_threadsstatus variable. -
Command-Line Format --slow-query-log[={OFF|ON}]System Variable slow_query_logScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value 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 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.“Slow” is determined by the value of the
long_query_timevariable. See Section 7.4.5, “The Slow Query Log”. -
Command-Line Format --slow-query-log-file=file_nameSystem Variable slow_query_log_fileScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value 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. -
Command-Line Format --socket={file_name|pipe_name}System Variable socketScope Global Dynamic No SET_VARHint AppliesNo Type String Default Value (Windows) MySQLDefault Value (Other) /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 sort_buffer_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 262144Minimum Value 32768Maximum Value (Windows) 4294967295Maximum Value (Other, 64-bit platforms) 18446744073709551615Maximum Value (Other, 32-bit platforms) 4294967295Unit bytes Each session that must perform 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. At minimum thesort_buffer_sizevalue must be large enough to accommodate fifteen tuples in the sort buffer. Also, increasing the value ofmax_sort_lengthmay require increasing the value ofsort_buffer_size. For more information, see Section 10.2.1.16, “ORDER BY Optimization”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 optimizer tries to work out how much space is needed but can allocate more, up to the limit. Setting it larger than required globally slows down most queries that perform sorts. 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.3.3.5, “Where MySQL Stores Temporary Files”.
The maximum permissible setting for
sort_buffer_sizeis 4GB−1. 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 sql_auto_is_nullScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFIf this variable is enabled, 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_name WHERE auto_col IS 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 14.15, “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_nulltoOFF.The default value of
sql_auto_is_nullisOFF. -
System Variable sql_big_selectsScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value ONIf set to
OFF, MySQL abortsSELECTstatements 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 isON, which permits allSELECTstatements.If you set the
max_join_sizesystem variable to a value other thanDEFAULT,sql_big_selectsis set toOFF. -
System Variable sql_buffer_resultScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFIf enabled,
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 isOFF. sql_generate_invisible_primary_keyCommand-Line Format --sql-generate-invisible-primary-key[={OFF|ON}]System Variable sql_generate_invisible_primary_keyScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFWhether this server adds a generated invisible primary key to any
InnoDBtable that is created without one.This variable is not replicated. In addition, even if set on the replica, it is ignored by replication applier threads; this means that, by default, a replica does not generate a primary key for any replicated table which, on the source, was created without one. You can cause the replica to generate invisible primary keys for such tables by setting
REQUIRE_TABLE_PRIMARY_KEY_CHECK = GENERATEas part of aCHANGE REPLICATION SOURCE TOstatement, optionally specifying a replication channel.For more information and examples, see Section 15.1.20.11, “Generated Invisible Primary Keys”.
-
System Variable sql_log_offScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFValid Values OFF(enable logging)ON(disable logging)This variable controls whether logging to the general query log is disabled for the current session (assuming that the general query log itself is enabled). The default value is
OFF(that is, enable logging). To disable or enable general query logging for the current session, set the sessionsql_log_offvariable toONorOFF.Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
-
Command-Line Format --sql-mode=nameSystem Variable sql_modeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Set Default Value ONLY_FULL_GROUP_BY STRICT_TRANS_TABLES NO_ZERO_IN_DATE NO_ZERO_DATE ERROR_FOR_DIVISION_BY_ZERO NO_ENGINE_SUBSTITUTIONValid Values ALLOW_INVALID_DATESANSI_QUOTESERROR_FOR_DIVISION_BY_ZEROHIGH_NOT_PRECEDENCEIGNORE_SPACENO_AUTO_VALUE_ON_ZERONO_BACKSLASH_ESCAPESNO_DIR_IN_CREATENO_ENGINE_SUBSTITUTIONNO_UNSIGNED_SUBTRACTIONNO_ZERO_DATENO_ZERO_IN_DATEONLY_FULL_GROUP_BYPAD_CHAR_TO_FULL_LENGTHPIPES_AS_CONCATREAL_AS_FLOATSTRICT_ALL_TABLESSTRICT_TRANS_TABLESTIME_TRUNCATE_FRACTIONALThe current server SQL mode, which can be set dynamically. For details, see Section 7.1.11, “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.
-
System Variable sql_notesScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONIf enabled (the default), diagnostics of
Notelevel incrementwarning_countand the server records them. If disabled,Notediagnostics do not incrementwarning_countand the server does not record them. mysqldump includes output to disable this variable so that reloading the dump file does not produce warnings for events that do not affect the integrity of the reload operation. -
System Variable sql_quote_show_createScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONIf enabled (the default), the server quotes identifiers for
SHOW CREATE TABLEandSHOW CREATE DATABASEstatements. If disabled, quoting is disabled. This option is enabled by default so that replication works for identifiers that require quoting. See Section 15.7.7.11, “SHOW CREATE TABLE Statement”, and Section 15.7.7.7, “SHOW CREATE DATABASE Statement”. -
Command-Line Format --sql-require-primary-key[={OFF|ON}]System Variable sql_require_primary_keyScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFWhether statements that create new tables or alter the structure of existing tables enforce the requirement that tables have a primary key.
Setting the session value of this system variable is a restricted operation. The session user must have privileges sufficient to set restricted session variables. See Section 7.1.9.1, “System Variable Privileges”.
Enabling this variable helps avoid performance problems in row-based replication that can occur when tables have no primary key. Suppose that a table has no primary key and an update or delete modifies multiple rows. On the replication source server, this operation can be performed using a single table scan but, when replicated using row-based replication, results in a table scan for each row to be modified on the replica. With a primary key, these table scans do not occur.
sql_require_primary_keyapplies to both base tables andTEMPORARYtables, and changes to its value are replicated to replica servers. The table must use MySQL storage engines that can participate in replication.When enabled,
sql_require_primary_keyhas these effects:Attempts to create a new table with no primary key fail with an error. This includes
CREATE TABLE ... LIKE. It also includesCREATE TABLE ... SELECT, unless theCREATE TABLEpart includes a primary key definition.Attempts to drop the primary key from an existing table fail with an error, with the exception that dropping the primary key and adding a primary key in the same
ALTER TABLEstatement is permitted.Dropping the primary key fails even if the table also contains a
UNIQUE NOT NULLindex.Attempts to import a table with no primary key fail with an error.
The
REQUIRE_TABLE_PRIMARY_KEY_CHECKoption of theCHANGE REPLICATION SOURCE TOstatement enables a replica to select its own policy for primary key checks. When the option is set toONfor a replication channel, the replica always uses the valueONfor thesql_require_primary_keysystem variable in replication operations, requiring a primary key. When the option is set toOFF, the replica always uses the valueOFFfor thesql_require_primary_keysystem variable in replication operations, so that a primary key is never required, even if the source required one. When theREQUIRE_TABLE_PRIMARY_KEY_CHECKoption is set toSTREAM, which is the default, the replica uses whatever value is replicated from the source for each transaction. With theSTREAMsetting for theREQUIRE_TABLE_PRIMARY_KEY_CHECKoption, if privilege checks are in use for the replication channel, thePRIVILEGE_CHECKS_USERaccount needs privileges sufficient to set restricted session variables, so that it can set the session value for thesql_require_primary_keysystem variable. With theONorOFFsettings, the account does not need these privileges. For more information, see Section 19.3.3, “Replication Privilege Checks”. -
System Variable sql_safe_updatesScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value OFFIf this variable is enabled,
UPDATEandDELETEstatements that do not use a key in theWHEREclause or aLIMITclause produce an error. This makes it possible to catchUPDATEandDELETEstatements where keys are not used properly and that would probably change or delete a large number of rows. The default value isOFF.For the mysql client,
sql_safe_updatescan be enabled by using the--safe-updatesoption. For more information, see Using Safe-Updates Mode (--safe-updates). -
System Variable sql_select_limitScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 18446744073709551615Minimum Value 0Maximum Value 18446744073709551615The maximum number of rows to return from
SELECTstatements. For more information, see Using Safe-Updates Mode (--safe-updates).The default value for a new connection is the maximum number of rows that the server permits per table. Typical default values are (232)−1 or (264)−1. If you have changed the limit, the default value can be restored by assigning a value of
DEFAULT.If a
SELECThas aLIMITclause, theLIMITtakes precedence over the value ofsql_select_limit. -
System Variable sql_warningsScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThis variable controls whether single-row
INSERTstatements produce an information string if warnings occur. The default isOFF. Set the value toONto produce an information string. -
Command-Line Format --ssl-ca=file_nameSystem Variable ssl_caScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe path name of the Certificate Authority (CA) certificate file in PEM format. The file contains a list of trusted SSL Certificate Authorities.
This variable can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl-capath=dir_nameSystem Variable ssl_capathScope Global Dynamic Yes SET_VARHint AppliesNo Type Directory name Default Value NULLThe path name of the directory that contains trusted SSL Certificate Authority (CA) certificate files in PEM format. You must run OpenSSL
rehashon the directory specified by this option prior to using it. On Linux systems, you can invokerehashlike this:$> openssl rehash path/to/directoryOn Windows platforms, you can use the
c_rehashscript in a command prompt, like this:\> c_rehash path/to/directorySee openssl-rehash for complete syntax and other information.
This variable is can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl-cert=file_nameSystem Variable ssl_certScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe path name of the server SSL public key certificate file in PEM format.
If the server is started with
ssl_certset to a certificate that uses any restricted cipher or cipher category, the server starts with support for encrypted connections disabled. For information about cipher restrictions, see Connection Cipher Configuration.This variable can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl-cipher=nameSystem Variable ssl_cipherScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value NULLThe list of permissible encryption ciphers for connections that use TLSv1.2. If no cipher in the list is supported, encrypted connections that use this TLS protocol do not work.
The list may include any of the following values:
ECDHE-ECDSA-AES128-GCM-SHA256ECDHE-ECDSA-AES256-GCM-SHA384ECDHE-RSA-AES128-GCM-SHA256ECDHE-RSA-AES256-GCM-SHA384ECDHE-ECDSA-CHACHA20-POLY1305ECDHE-RSA-CHACHA20-POLY1305ECDHE-ECDSA-AES256-CCMECDHE-ECDSA-AES128-CCMDHE-RSA-AES128-GCM-SHA256DHE-RSA-AES256-GCM-SHA384DHE-RSA-AES256-CCMDHE-RSA-AES128-CCMDHE-RSA-CHACHA20-POLY1305
Trying to include any values in the cipher list that are not shown here when setting this variable raises an error (
ER_BLOCKED_CIPHER).For greatest portability, the cipher list should be a list of one or more cipher names, separated by colons. The following example shows two cipher names separated by a colon:
[mysqld] ssl_cipher="DHE-RSA-AES128-GCM-SHA256:AES128-SHA"OpenSSL supports the syntax for specifying ciphers described in the OpenSSL documentation at https://www.openssl.org/docs/manmaster/man1/ciphers.html.
For information about which encryption ciphers MySQL supports, see Section 8.3.2, “Encrypted Connection TLS Protocols and Ciphers”.
This variable can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl-crl=file_nameSystem Variable ssl_crlScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe path name of the file containing certificate revocation lists in PEM format.
This variable can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl-crlpath=dir_nameSystem Variable ssl_crlpathScope Global Dynamic Yes SET_VARHint AppliesNo Type Directory name Default Value NULLThe path of the directory that contains certificate revocation-list files in PEM format.
This variable can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl-fips-mode={OFF|ON|STRICT}Deprecated Yes System Variable ssl_fips_modeScope Global Dynamic No SET_VARHint AppliesNo Type Enumeration Default Value OFFValid Values OFF(or 0)ON(or 1)STRICT(or 2)Controls whether to enable FIPS mode on the server side. The
ssl_fips_modesystem variable differs from otherssl_system variables in that it is not used to control whether the server permits encrypted connections, but rather to affect which cryptographic operations are permitted. See Section 8.8, “FIPS Support”.xxxThese
ssl_fips_modevalues are permitted:OFF(or 0): Disable FIPS mode.ON(or 1): Enable FIPS mode.STRICT(or 2): Enable “strict” FIPS mode.
NoteIf the OpenSSL FIPS Object Module is not available, the only permitted value for
ssl_fips_modeisOFF. In this case, settingssl_fips_modetoONorSTRICTat startup causes the server to produce an error message and exit.This option is deprecated and made read-only. Expect it to be removed in a future version of MySQL.
-
Command-Line Format --ssl-key=file_nameSystem Variable ssl_keyScope Global Dynamic Yes SET_VARHint AppliesNo Type File name Default Value NULLThe path name of the server SSL private key file in PEM format. For better security, use a certificate with an RSA key size of at least 2048 bits.
If the key file is protected by a passphrase, the server prompts the user for the passphrase. The password must be given interactively; it cannot be stored in a file. If the passphrase is incorrect, the program continues as if it could not read the key.
This variable can be modified at runtime to affect the TLS context the server uses for new connections established after the execution of
ALTER INSTANCE RELOAD TLSor after a restart if the variable value was persisted. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections. -
Command-Line Format --ssl_session_cache_mode={ON|OFF}System Variable ssl_session_cache_modeScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONValid Values ONOFFControls whether to enable the session cache in memory on the server side and session-ticket generation by the server. The default mode is
ON(enable session cache mode). A change to thessl_session_cache_modesystem variable has an effect only after theALTER INSTANCE RELOAD TLSstatement has been executed, or after a restart if the variable value was persisted.These
ssl_session_cache_modevalues are permitted:ON: Enable session cache mode.OFF: Disable session cache mode.
The server does not advertise its support for session resumption if the value of this system variable is
OFF. When running on OpenSSL 1.0.xthe session tickets are always generated, but the tickets are not usable whenssl_session_cache_modeis enabled.The current value in effect for
ssl_session_cache_modecan be observed with theSsl_session_cache_modestatus variable. -
Command-Line Format --ssl_session_cache_timeoutSystem Variable ssl_session_cache_timeoutScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 300Minimum Value 0Maximum Value 84600Unit seconds Sets a period of time during which prior session reuse is permitted when establishing a new encrypted connection to the server, provided the
ssl_session_cache_modesystem variable is enabled and prior session data is available. If the session timeout expires, a session can no longer be reused.The default value is 300 seconds and the maximum value is 84600 (or one day in seconds). A change to the
ssl_session_cache_timeoutsystem variable has an effect only after theALTER INSTANCE RELOAD TLSstatement has been executed, or after a restart if the variable value was persisted. The current value in effect forssl_session_cache_timeoutcan be observed with theSsl_session_cache_timeoutstatus variable. -
System Variable statement_idScope Session Dynamic No SET_VARHint AppliesNo Type Integer Each statement executed in the current session is assigned a sequence number. This can be used together with the
session_track_system_variablessystem variable to identify this statement in Performance Schema tables such as theevents_statements_historytable. -
Command-Line Format --stored-program-cache=#System Variable stored_program_cacheScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 256Minimum Value 16Maximum Value 524288Sets a soft upper limit for the number of cached stored routines per connection. The value of this variable is specified in terms of the number of stored routines held in each of the two caches maintained by the MySQL Server for, respectively, stored procedures and stored functions.
Whenever a stored routine is executed this cache size is checked before the first or top-level statement in the routine is parsed; if the number of routines of the same type (stored procedures or stored functions according to which is being executed) exceeds the limit specified by this variable, the corresponding cache is flushed and memory previously allocated for cached objects is freed. This allows the cache to be flushed safely, even when there are dependencies between stored routines.
The stored procedure and stored function caches exists in parallel with the stored program definition cache partition of the dictionary object cache. The stored procedure and stored function caches are per connection, while the stored program definition cache is shared. The existence of objects in the stored procedure and stored function caches have no dependence on the existence of objects in the stored program definition cache, and vice versa. For more information, see Section 16.4, “Dictionary Object Cache”.
stored_program_definition_cacheCommand-Line Format --stored-program-definition-cache=#System Variable stored_program_definition_cacheScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 256Minimum Value 256Maximum Value 524288Defines a limit for the number of stored program definition objects, both used and unused, that can be kept in the dictionary object cache.
Unused stored program definition objects are only kept in the dictionary object cache when the number in use is less than the capacity defined by
stored_program_definition_cache.A setting of 0 means that stored program definition objects are only kept in the dictionary object cache while they are in use.
The stored program definition cache partition exists in parallel with the stored procedure and stored function caches that are configured using the
stored_program_cacheoption.The
stored_program_cacheoption sets a soft upper limit for the number of cached stored procedures or functions per connection, and the limit is checked each time a connection executes a stored procedure or function. The stored program definition cache partition, on the other hand, is a shared cache that stores stored program definition objects for other purposes. The existence of objects in the stored program definition cache partition has no dependence on the existence of objects in the stored procedure cache or stored function cache, and vice versa.For related information, see Section 16.4, “Dictionary Object Cache”.
-
Command-Line Format --super-read-only[={OFF|ON}]System Variable super_read_onlyScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFIf the
read_onlysystem variable is enabled, the server permits no client updates except from users who have theCONNECTION_ADMINprivilege (or the deprecatedSUPERprivilege). If thesuper_read_onlysystem variable is also enabled, the server prohibits client updates even from users who haveCONNECTION_ADMINorSUPER. See the description of theread_onlysystem variable for a description of read-only mode and information about howread_onlyandsuper_read_onlyinteract.Client updates prevented when
super_read_onlyis enabled include operations that do not necessarily appear to be updates, such asCREATE FUNCTION(to install a loadable function),INSTALL PLUGIN, andINSTALL COMPONENT. These operations are prohibited because they involve changes to tables in themysqlsystem schema.Similarly, if the Event Scheduler is enabled, enabling the
super_read_onlysystem variable prevents it from updating event “last executed” timestamps in theeventsdata dictionary table. This causes the Event Scheduler to stop the next time it tries to execute a scheduled event, after writing a message to the server error log. (In this situation theevent_schedulersystem variable does not change fromONtoOFF. An implication is that this variable rejects the DBA intent that the Event Scheduler be enabled or disabled, where its actual status of started or stopped may be distinct.). Ifsuper_read_onlyis subsequently disabled after being enabled, the server automatically restarts the Event Scheduler as needed.Changes to
super_read_onlyon a replication source server are not replicated to replica servers. The value can be set on a replica independent of the setting on the source. -
Command-Line Format --syseventlog.facility=valueSystem Variable syseventlog.facilityScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value daemonThe facility for error log output written to
syslog(what type of program is sending the message). This variable is unavailable unless thelog_sink_syseventlogerror log component is installed. See Section 7.4.2.8, “Error Logging to the System Log”.The permitted values can vary per operating system; consult your system
syslogdocumentation.This variable does not exist on Windows.
-
Command-Line Format --syseventlog.include-pid[={OFF|ON}]System Variable syseventlog.include_pidScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONWhether to include the server process ID in each line of error log output written to
syslog. This variable is unavailable unless thelog_sink_syseventlogerror log component is installed. See Section 7.4.2.8, “Error Logging to the System Log”.This variable does not exist on Windows.
-
Command-Line Format --syseventlog.tag=tagSystem Variable syseventlog.tagScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value empty stringThe tag to be added to the server identifier in error log output written to
syslogor the Windows Event Log. This variable is unavailable unless thelog_sink_syseventlogerror log component is installed. See Section 7.4.2.8, “Error Logging to the System Log”.By default, no tag is set, so the server identifier is simply
MySQLon Windows, andmysqldon other platforms. If a tag value oftagis specified, it is appended to the server identifier with a leading hyphen, resulting in asyslogidentifier ofmysqld-(ortagMySQL-on Windows).tagOn Windows, to use a tag that does not already exist, the server must be run from an account with Administrator privileges, to permit creation of a registry entry for the tag. Elevated privileges are not required if the tag already exists.
-
System Variable system_time_zoneScope Global Dynamic No SET_VARHint AppliesNo Type String The server system time zone. When the server begins executing, it inherits a time zone setting from the machine defaults, possibly modified by the environment of the account used for running the server or the startup script. The value is used to set
system_time_zone. To explicitly specify the system time zone, set theTZenvironment variable or use the--timezoneoption of the mysqld_safe script.In addition to startup time initialization, if the server host time zone changes (for example, due to daylight saving time),
system_time_zonereflects that change, which has these implications for applications:Queries that reference
system_time_zonewill get one value before a daylight saving change and a different value after the change.For queries that begin executing before a daylight saving change and end after the change, the
system_time_zoneremains constant within the query because the value is usually cached at the beginning of execution.
The
system_time_zonevariable differs from thetime_zonevariable. Although they might have the same value, the latter variable is used to initialize the time zone for each client that connects. See Section 7.1.15, “MySQL Server Time Zone Support”. -
Command-Line Format --table-definition-cache=#System Variable table_definition_cacheScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value -1(signifies autosizing; do not assign this literal value)Minimum Value 400Maximum Value 524288The number of table definitions that can be stored in the table 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. The minimum value is 400. The default value is based on the following formula, capped to a limit of 2000:
MIN(400 + table_open_cache / 2, 2000)For
InnoDB, thetable_definition_cachesetting acts as a soft limit for the number of table instances in the dictionary object cache and the number file-per-table tablespaces that can be open at one time.If the number of table instances in the dictionary object cache exceeds the
table_definition_cachelimit, an LRU mechanism begins marking table instances for eviction and eventually removes them from the dictionary object cache. The number of open tables with cached metadata can be higher than thetable_definition_cachelimit due to table instances with foreign key relationships, which are not placed on the LRU list.The number of file-per-table tablespaces that can be open at one time is limited by both the
table_definition_cacheandinnodb_open_filessettings. If both variables are set, the highest setting is used. If neither variable is set, thetable_definition_cachesetting, which has a higher default value, is used. If the number of open tablespaces exceeds the limit defined bytable_definition_cacheorinnodb_open_files, an LRU mechanism searches the LRU list for tablespace files that are fully flushed and not currently being extended. This process is performed each time a new tablespace is opened. Only inactive tablespaces are closed.The table definition cache exists in parallel with the table definition cache partition of the dictionary object cache. Both caches store table definitions but serve different parts of the MySQL server. Objects in one cache have no dependence on the existence of objects in the other. For more information, see Section 16.4, “Dictionary Object Cache”.
table_encryption_privilege_checkCommand-Line Format --table-encryption-privilege-check[={OFF|ON}]System Variable table_encryption_privilege_checkScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFControls the
TABLE_ENCRYPTION_ADMINprivilege check that occurs when creating or altering a schema or general tablespace with encryption that differs from thedefault_table_encryptionsetting, or when creating or altering a table with an encryption setting that differs from the default schema encryption. The check is disabled by default.Setting
table_encryption_privilege_checkat runtime requires theSUPERprivilege.table_encryption_privilege_checksupportsSET PERSISTandSET PERSIST_ONLYsyntax. See Section 7.1.9.3, “Persisted System Variables”.For more information, see Defining an Encryption Default for Schemas and General Tablespaces.
-
Command-Line Format --table-open-cache=#System Variable table_open_cacheScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 4000Minimum Value 1Maximum Value 524288The number of open tables for all threads. Increasing this value increases the number of file descriptors that mysqld requires. The effective value of this variable is the greater of the effective value of
open_files_limit- 10 -the effective value ofmax_connections/ 2, and 400; that isMAX( (open_files_limit - 10 - max_connections) / 2, 400 )You can check whether you need to increase the table cache by checking the
Opened_tablesstatus variable. 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 10.4.3.1, “How MySQL Opens and Closes Tables”. -
Command-Line Format --table-open-cache-instances=#System Variable table_open_cache_instancesScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 16Minimum Value 1Maximum Value 64The number of open tables cache instances. To improve scalability by reducing contention among sessions, the open tables cache can be partitioned into several smaller cache instances of size
table_open_cache/table_open_cache_instances. A session needs to lock only one instance to access it for DML statements. This segments cache access among instances, permitting higher performance for operations that use the cache when there are many sessions accessing tables. (DDL statements still require a lock on the entire cache, but such statements are much less frequent than DML statements.)A value of 8 or 16 is recommended on systems that routinely use 16 or more cores. However, if you have many large triggers on your tables that cause a high memory load, the default setting for
table_open_cache_instancesmight lead to excessive memory usage. In that situation, it can be helpful to settable_open_cache_instancesto 1 in order to restrict memory usage. -
Command-Line Format --tablespace-definition-cache=#System Variable tablespace_definition_cacheScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 256Minimum Value 256Maximum Value 524288Defines a limit for the number of tablespace definition objects, both used and unused, that can be kept in the dictionary object cache.
Unused tablespace definition objects are only kept in the dictionary object cache when the number in use is less than the capacity defined by
tablespace_definition_cache.A setting of
0means that tablespace definition objects are only kept in the dictionary object cache while they are in use.For more information, see Section 16.4, “Dictionary Object Cache”.
-
Command-Line Format --temptable-max-mmap=#System Variable temptable_max_mmapScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 2^64-1Unit bytes Defines the maximum amount of memory (in bytes) the TempTable storage engine is permitted to allocate from memory-mapped temporary files before it starts storing data to
InnoDBinternal temporary tables on disk. A setting of 0 (default) disables allocation of memory from memory-mapped temporary files. For more information, see Section 10.4.4, “Internal Temporary Table Use in MySQL”.Before MySQL 8.4, this option was set to 1 GiB instead of 0.
-
Command-Line Format --temptable-max-ram=#System Variable temptable_max_ramScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 3% of total memory: min 1 GB, max 4 GBMinimum Value 2097152Maximum Value 2^64-1Unit bytes Defines the maximum amount of memory that can be occupied by the
TempTablestorage engine before it starts storing data on disk. The default value is 3% of total memory available on the server, with a minimum and maximum default range of 1-4 GiB. For more information, see Section 10.4.4, “Internal Temporary Table Use in MySQL”.Before MySQL 8.4, the default value was always 1 GiB.
-
Command-Line Format --temptable-use-mmap[={OFF|ON}]Deprecated Yes System Variable temptable_use_mmapScope Global Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFDefines whether the TempTable storage engine allocates space for internal in-memory temporary tables as memory-mapped temporary files when the amount of memory occupied by the TempTable storage engine exceeds the limit defined by the
temptable_max_ramvariable. Whentemptable_use_mmapis disabled (default), the TempTable storage engine usesInnoDBon-disk internal temporary tables instead. For more information, see Section 10.4.4, “Internal Temporary Table Use in MySQL”. -
Command-Line Format --thread-cache-size=#System Variable thread_cache_sizeScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value -1(signifies autosizing; do not assign this literal value)Minimum Value 0Maximum 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 7.1.10, “Server Status Variables”.The default value is based on the following formula, capped to a limit of 100:
8 + (max_connections / 100) -
Command-Line Format --thread-handling=nameSystem Variable thread_handlingScope Global Dynamic No SET_VARHint AppliesNo Type Enumeration Default Value one-thread-per-connectionValid Values no-threadsone-thread-per-connectionloaded-dynamicallyThe 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),one-thread-per-connection(the server uses one thread to handle each client connection), andloaded-dynamically(set by the thread pool plugin when it initializes).no-threadsis useful for debugging under Linux; see Section 7.9, “Debugging MySQL”. -
Command-Line Format --thread-pool-algorithm=#System Variable thread_pool_algorithmScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 1This variable controls which algorithm the thread pool plugin uses:
0: Use a conservative low-concurrency algorithm.1: Use an aggressive high-currency algorithm which performs better with optimal thread counts, but performance may be degraded if the number of connections reaches extremely high values.
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
thread_pool_dedicated_listenersCommand-Line Format --thread-pool-dedicated-listenersSystem Variable thread_pool_dedicated_listenersScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFDedicates a listener thread in each thread group to listen for incoming statements from connections assigned to the group.
OFF: (Default) Disables dedicated listener threads.ON: Dedicates a listener thread in each thread group to listen for incoming statements from connections assigned to the group. Dedicated listener threads do not execute queries.
Enabling
thread_pool_dedicated_listenersis only useful when a transaction limit is defined bythread_pool_max_transactions_limit. Otherwise,thread_pool_dedicated_listenersshould not be enabled.This variable is available only with MySQL Enterprise Edition, and not supported in MySQL 8.4.
thread_pool_high_priority_connectionCommand-Line Format --thread-pool-high-priority-connection=#System Variable thread_pool_high_priority_connectionScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 1This variable affects queuing of new statements prior to execution. If the value is 0 (false, the default), statement queuing uses both the low-priority and high-priority queues. If the value is 1 (true), queued statements always go to the high-priority queue.
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
-
Command-Line Format --thread-pool-longrun-trx-limit=#System Variable thread_pool_longrun_trx_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 2000Minimum Value 10Maximum Value 60*60*24Unit ms When
thread_pool_max_transactions_limitis in use, there is a maximum number of transactions that can be active in each thread group. If entire number available is being used by long-running transactions, any additional transaction assigned to the group blocks until one of the long-running transactions is completed, which users can perceive as an inexplicable hang.To mitigate this issue, the limit for a given thread group is suspended if all of the threads using up the transaction maximum have been executing longer than the interval (in milliseconds) specified by
thread_pool_longrun_trx_limit. When the number of long-running transactions decreases,thread_pool_max_transactions_limitcan be (and is) enabled again. In order for this to happen, the number of ongoing transactions must be less thanthread_pool_max_transactions_limit / 2for the interval defined as shown:MIN( MAX(thread_pool_longrun_trx_limit * 15, 5000), 30000)This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
thread_pool_max_active_query_threadsCommand-Line Format --thread-pool-max-active-query-threadsSystem Variable thread_pool_max_active_query_threadsScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 512The maximum permissible number of active (running) query threads per group. If the value is 0, the thread pool plugin uses up to as many threads as are available.
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
thread_pool_max_transactions_limitCommand-Line Format --thread-pool-max-transactions-limitSystem Variable thread_pool_max_transactions_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 1000000The maximum number of transactions permitted by the thread pool plugin. Defining a transaction limit binds a thread to a transaction until it commits, which helps stabilize throughput during high concurrency.
The default value of 0 means that there is no transaction limit. The variable is dynamic but cannot be changed from 0 to a higher value at runtime and vice versa. A non-zero value at startup permits dynamic configuration at runtime. The
CONNECTION_ADMINprivilege is required to configurethread_pool_max_transactions_limitat runtime.When you define a transaction limit, enabling
thread_pool_dedicated_listenerscreates a dedicated listener thread in each thread group. The additional dedicated listener thread consumes more resources and affects thread pool performance.thread_pool_dedicated_listenersshould therefore be used cautiously.When the limit defined by
thread_pool_max_transactions_limithas been reached, new connections or transactions on existing connections may appear to hang until one or more existing transactions are completed. It should be possible in many cases to mitigate this issue by settingthread_pool_longrun_trx_limitso that the transaction maximum can be relaxed when the number of ongoing transactions matches it for a given length of time. If existing connections continue to be blocked or long-running even after attempting this, a privileged connection may be required to access the server to increase the limit, remove the limit, or kill running transactions. See Privileged Connections.This variable is available only with MySQL Enterprise Edition, and not supported in MySQL 8.4.
thread_pool_max_unused_threadsCommand-Line Format --thread-pool-max-unused-threads=#System Variable thread_pool_max_unused_threadsScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 4096The maximum permitted number of unused threads in the thread pool. This variable makes it possible to limit the amount of memory used by sleeping threads.
A value of 0 (the default) means no limit on the number of sleeping threads. A value of
NwhereNis greater than 0 means 1 consumer thread andN−1 reserve threads. In this case, if a thread is ready to sleep but the number of sleeping threads is already at the maximum, the thread exits rather than going to sleep.A sleeping thread is either sleeping as a consumer thread or a reserve thread. The thread pool permits one thread to be the consumer thread when sleeping. If a thread goes to sleep and there is no existing consumer thread, it sleeps as a consumer thread. When a thread must be woken up, a consumer thread is selected if there is one. A reserve thread is selected only when there is no consumer thread to wake up.
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
-
Command-Line Format --thread-pool-prio-kickup-timer=#System Variable thread_pool_prio_kickup_timerScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1000Minimum Value 0Maximum Value 4294967294Unit milliseconds This variable affects statements waiting for execution in the low-priority queue. The value is the number of milliseconds before a waiting statement is moved to the high-priority queue. The default is 1000 (1 second).
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
thread_pool_query_threads_per_groupCommand-Line Format --thread-pool-query-threads-per-groupSystem Variable thread_pool_query_threads_per_groupScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 1Minimum Value 1Maximum Value 4096The maximum number of query threads permitted in a thread group. The maximum value is 4096, but if
thread_pool_max_transactions_limitis set,thread_pool_query_threads_per_groupmust not exceed that value.The default value of 1 means there is one active query thread in each thread group, which works well for many loads. When you are using the high concurrency thread pool algorithm (
thread_pool_algorithm = 1), consider increasing the value if you experience slower response times due to long-running transactions.The
CONNECTION_ADMINprivilege is required to configurethread_pool_query_threads_per_groupat runtime.If you decrease the value of
thread_pool_query_threads_per_groupat runtime, threads that are currently running user queries are allowed to complete, then moved to the reserve pool or terminated. if you increment the value at runtime and the thread group needs more threads, these are taken from the reserve pool if possible, otherwise they are created.This variable is available only with MySQL Enterprise Edition, and not supported in MySQL 8.4.
-
Command-Line Format --thread-pool-size=#System Variable thread_pool_sizeScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 16Minimum Value 1Maximum Value 512The number of thread groups in the thread pool. This is the most important parameter controlling thread pool performance. It affects how many statements can execute simultaneously. If a value outside the range of permissible values is specified, the thread pool plugin does not load and the server writes a message to the error log.
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
-
Command-Line Format --thread-pool-stall-limit=#System Variable thread_pool_stall_limitScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 6Minimum Value 4Maximum Value 600Unit milliseconds * 10 This variable affects executing statements. The value is the amount of time a statement has to finish after starting to execute before it becomes defined as stalled, at which point the thread pool permits the thread group to begin executing another statement. The value is measured in 10 millisecond units, so the default of 6 means 60ms. Short wait values permit threads to start more quickly. Short values are also better for avoiding deadlock situations. Long wait values are useful for workloads that include long-running statements, to avoid starting too many new statements while the current ones execute.
This variable is available only if the thread pool plugin is enabled. See Section 7.6.3, “MySQL Enterprise Thread Pool”.
-
Command-Line Format --thread-pool-transaction-delaySystem Variable thread_pool_transaction_delayScope Global Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 0Minimum Value 0Maximum Value 300000The delay period before executing a new transaction, in milliseconds. The maximum value is 300000 (5 minutes).
A transaction delay can be used in cases where parallel transactions affect the performance of other operations due to resource contention. For example, if parallel transactions affect index creation or an online buffer pool resizing operation, you can configure a transaction delay to reduce resource contention while those operations are running.
Worker threads sleep for the number of milliseconds specified by
thread_pool_transaction_delaybefore executing a new transaction.The
thread_pool_transaction_delaysetting does not affect queries issued from a privileged connection (a connection assigned to theAdminthread group). These queries are not subject to a configured transaction delay. -
Command-Line Format --thread-stack=#System Variable thread_stackScope Global Dynamic No SET_VARHint AppliesNo Type Integer Default Value 1048576Minimum Value 131072Maximum Value (64-bit platforms) 18446744073709550592Maximum Value (32-bit platforms) 4294966272Unit bytes Block Size 1024The stack size for each thread. The default 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.
-
System Variable time_zoneScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type String Default Value SYSTEMMinimum Value -13:59Maximum Value +14:00The 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 7.1.15, “MySQL Server Time Zone Support”.NoteIf set to
SYSTEM, every MySQL function call that requires a time zone calculation makes a system library call to determine the current system time zone. This call may be protected by a global mutex, resulting in contention. -
System Variable timestampScope Session Dynamic Yes SET_VARHint AppliesYes Type Numeric Default Value UNIX_TIMESTAMP()Minimum Value 1Maximum Value 2147483647Set 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'format) orYYYY-MM-DD hh:mm:ss'DEFAULT.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.timestampis aDOUBLErather thanBIGINTbecause its value includes a microseconds part. The maximum value corresponds to'2038-01-19 03:14:07'UTC, the same as for theTIMESTAMPdata type.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 a synonym forNOW(), in which caseSET timestampaffects both functions. tls_certificates_enforced_validationCommand-Line Format --tls-certificates-enforced-validation[={OFF|ON}]System Variable tls_certificates_enforced_validationScope Global Dynamic No SET_VARHint AppliesNo Type Boolean Default Value OFFDuring startup, the server ensures that the location of each required SSL certificate file is present in the default data directory if the file locations are not given on the command line. However, the server does not validate the certificate files and, as a result, it is able to start with an invalid certificate. The
tls_certificates_enforced_validationsystem variable controls whether certificate validation is enforced at startup. Discovery of an invalid certificate halts the startup execution when validation enforcement is enabled. By default, certificate validation enforcement is disabled (OFF).Validation enforcement can be enabled by specifying the
--tls-certificates-enforced-validationoption on the command line with or without theONvalue. With validation enforcement enabled, certificates are also validated at the time of reloading them through theALTER INSTANCE RELOAD TLSstatement. This system variable cannot be persisted across reboots. For more information, see Configuring Certificate Validation Enforcement.-
Command-Line Format --tls-ciphersuites=ciphersuite_listSystem Variable tls_ciphersuitesScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value NULLWhich ciphersuites the server permits for encrypted connections that use TLSv1.3. The value is a list of zero or more colon-separated ciphersuite names from among those listed here:
TLS_AES_128_GCM_SHA256TLS_AES_256_GCM_SHA384TLS_CHACHA20_POLY1305_SHA256TLS_AES_128_CCM_SHA256
Trying to include any values in the cipher list that are not shown here when setting this variable raises an error (
ER_BLOCKED_CIPHER).The ciphersuites that can be named for this variable depend on the SSL library used to compile MySQL. If this variable is not set, its default value is
NULL, which means that the server permits the default set of ciphersuites. If the variable is set to the empty string, no ciphersuites are enabled and encrypted connections cannot be established. For more information, see Section 8.3.2, “Encrypted Connection TLS Protocols and Ciphers”. -
Command-Line Format --tls-version=protocol_listSystem Variable tls_versionScope Global Dynamic Yes SET_VARHint AppliesNo Type String Default Value TLSv1.2,TLSv1.3Which protocols the server permits for encrypted connections. The value is a list of one or more comma-separated protocol names, which are not case-sensitive. The protocols that can be named for this variable depend on the SSL library used to compile MySQL. Permitted protocols should be chosen such as not to leave “holes” in the list. For details, see Section 8.3.2, “Encrypted Connection TLS Protocols and Ciphers”.
This variable can be modified at runtime to affect the TLS context the server uses for new connections. See Server-Side Runtime Configuration and Monitoring for Encrypted Connections.
ImportantMySQL 8.4 does not support the TLSv1 and TLSv1.1 connection protocols. See Removal of Support for the TLSv1 and TLSv1.1 Protocols for more information.
Support for the TLSv1.3 protocol is available in MySQL 8.4, provided that MySQL Server was compiled using OpenSSL 1.1.1 or higher. The server checks the version of OpenSSL at startup, and if it is lower than 1.1.1, TLSv1.3 is removed from the default value for the system variable. In that case, the default is
TLSv1.2.
Setting this variable to an empty string disables encrypted connections.
-
Command-Line Format --tmp-table-size=#System Variable tmp_table_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Integer Default Value 16777216Minimum Value 1024Maximum Value 18446744073709551615Unit bytes Defines the maximum size of internal in-memory temporary tables created by the
MEMORYandTempTablestorage engines. If an internal in-memory temporary table exceeds this size, it is automatically converted to an on-disk internal temporary table.The
tmp_table_sizevariable does not apply to user-createdMEMORYtables. User-createdTempTabletables are not supported.When using the
MEMORYstorage engine for internal in-memory temporary tables, the actual size limit is the smaller oftmp_table_sizeandmax_heap_table_size. Themax_heap_table_sizesetting does not apply toTempTabletables.Increase the value of
tmp_table_size(andmax_heap_table_sizeif necessary when using theMEMORYstorage engine for internal in-memory temporary tables) 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
Created_tmp_disk_tablesandCreated_tmp_tablesvalues.See also Section 10.4.4, “Internal Temporary Table Use in MySQL”.
-
Command-Line Format --tmpdir=dir_nameSystem Variable tmpdirScope Global Dynamic No SET_VARHint AppliesNo Type Directory name The path of the directory to use for creating temporary files. It might be useful if your default
/tmpdirectory resides on a partition that is too small to hold 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.tmpdircan be a non-permanent location, such as a directory on a memory-based file system or a directory that is cleared when the server host restarts. If the MySQL server is acting as a replica, and you are using a non-permanent location fortmpdir, consider setting a different temporary directory for the replica using thereplica_load_tmpdirvariable. For a replica, the temporary files used to replicateLOAD DATAstatements are stored in this directory, so with a permanent location they can survive machine restarts, although replication can now continue after a restart if the temporary files have been removed.For more information about the storage location of temporary files, see Section B.3.3.5, “Where MySQL Stores Temporary Files”.
-
Command-Line Format --transaction-alloc-block-size=#System Variable transaction_alloc_block_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 8192Minimum Value 1024Maximum Value 131072Unit bytes Block 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-isolation=nameSystem Variable transaction_isolationScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Enumeration Default Value REPEATABLE-READValid Values READ-UNCOMMITTEDREAD-COMMITTEDREPEATABLE-READSERIALIZABLEThe transaction isolation level. The default is
REPEATABLE-READ.The transaction isolation level has three scopes: global, session, and next transaction. This three-scope implementation leads to some nonstandard isolation-level assignment semantics, as described later.
To set the global transaction isolation level at startup, use the
--transaction-isolationserver option.At runtime, the isolation level can be set directly using the
SETstatement to assign a value to thetransaction_isolationsystem variable, or indirectly using theSET TRANSACTIONstatement. If you settransaction_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, use thisSETstatement to set the global value:SET GLOBAL transaction_isolation = 'READ-COMMITTED';Setting the global
transaction_isolationvalue sets the isolation level for all subsequent sessions. Existing sessions are unaffected.To set the session or next-level
transaction_isolationvalue, use theSETstatement. For most session system variables, these statements are equivalent ways to set the value:SET @@SESSION.var_name = value; SET SESSION var_name = value; SET var_name = value; SET @@var_name = value;As mentioned previously, the transaction isolation level has a next-transaction scope, in addition to the global and session scopes. To enable the next-transaction scope to be set,
SETsyntax for assigning session system variable values has nonstandard semantics fortransaction_isolation:To set the session isolation level, use any of these syntaxes:
SET @@SESSION.transaction_isolation = value; SET SESSION transaction_isolation = value; SET transaction_isolation = value;For each of those syntaxes, these semantics apply:
Sets the isolation level for all subsequent transactions performed within the session.
Permitted within transactions, but does not affect the current ongoing transaction.
If executed between transactions, overrides any preceding statement that sets the next-transaction isolation level.
Corresponds to
SET SESSION TRANSACTION ISOLATION LEVEL(with theSESSIONkeyword).
To set the next-transaction isolation level, use this syntax:
SET @@transaction_isolation = value;For that syntax, these semantics apply:
Sets the isolation level only for the next single transaction performed within the session.
Subsequent transactions revert to the session isolation level.
Not permitted within transactions.
Corresponds to
SET TRANSACTION ISOLATION LEVEL(without theSESSIONkeyword).
For more information about
SET TRANSACTIONand its relationship to thetransaction_isolationsystem variable, see Section 15.3.7, “SET TRANSACTION Statement”. -
Command-Line Format --transaction-prealloc-size=#Deprecated Yes System Variable transaction_prealloc_sizeScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 4096Minimum Value 1024Maximum Value 131072Unit bytes Block 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 makingtransaction_prealloc_sizesufficiently large to contain all statements within a single transaction, you can avoid manymalloc()calls.transaction_prealloc_sizeis deprecated, and setting this variable no longer has any effect. Expecttransaction_prealloc_sizeto be removed in a future release of MySQL. -
Command-Line Format --transaction-read-only[={OFF|ON}]System Variable transaction_read_onlyScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value OFFThe transaction access mode. The value can be
OFF(read/write; the default) orON(read only).The transaction access mode has three scopes: global, session, and next transaction. This three-scope implementation leads to some nonstandard access-mode assignment semantics, as described later.
To set the global transaction access mode at startup, use the
--transaction-read-onlyserver option.At runtime, the access mode can be set directly using the
SETstatement to assign a value to thetransaction_read_onlysystem variable, or indirectly using theSET TRANSACTIONstatement. For example, use thisSETstatement to set the global value:SET GLOBAL transaction_read_only = ON;Setting the global
transaction_read_onlyvalue sets the access mode for all subsequent sessions. Existing sessions are unaffected.To set the session or next-level
transaction_read_onlyvalue, use theSETstatement. For most session system variables, these statements are equivalent ways to set the value:SET @@SESSION.var_name = value; SET SESSION var_name = value; SET var_name = value; SET @@var_name = value;As mentioned previously, the transaction access mode has a next-transaction scope, in addition to the global and session scopes. To enable the next-transaction scope to be set,
SETsyntax for assigning session system variable values has nonstandard semantics fortransaction_read_only,To set the session access mode, use any of these syntaxes:
SET @@SESSION.transaction_read_only = value; SET SESSION transaction_read_only = value; SET transaction_read_only = value;For each of those syntaxes, these semantics apply:
Sets the access mode for all subsequent transactions performed within the session.
Permitted within transactions, but does not affect the current ongoing transaction.
If executed between transactions, overrides any preceding statement that sets the next-transaction access mode.
Corresponds to
SET SESSION TRANSACTION {READ WRITE | READ ONLY}(with theSESSIONkeyword).
To set the next-transaction access mode, use this syntax:
SET @@transaction_read_only = value;For that syntax, these semantics apply:
Sets the access mode only for the next single transaction performed within the session.
Subsequent transactions revert to the session access mode.
Not permitted within transactions.
Corresponds to
SET TRANSACTION {READ WRITE | READ ONLY}(without theSESSIONkeyword).
For more information about
SET TRANSACTIONand its relationship to thetransaction_read_onlysystem variable, see Section 15.3.7, “SET TRANSACTION Statement”. -
System Variable unique_checksScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value ONIf 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[={OFF|ON}]System Variable updatable_views_with_limitScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value 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.
For use with MySQL HeatWave only. See System Variables, for more information.
validate_password.xxxThe
validate_passwordcomponent implements a set of system variables having names of the formvalidate_password.. These variables affect password testing by that component; see Section 8.4.3.2, “Password Validation Options and Variables”.xxxThe version number for the server. The value might also include a suffix indicating server build or configuration information.
-debugindicates that the server was built with debugging support enabled.-
System Variable version_commentScope Global Dynamic No SET_VARHint AppliesNo Type String The CMake configuration program has a
COMPILATION_COMMENT_SERVERoption that permits a comment to be specified when building MySQL. This variable contains the value of that comment. -
System Variable version_compile_machineScope Global Dynamic No SET_VARHint AppliesNo Type String The type of the server binary.
-
System Variable version_compile_osScope Global Dynamic No SET_VARHint AppliesNo Type String The type of operating system on which MySQL was built.
-
System Variable version_compile_zlibScope Global Dynamic No SET_VARHint AppliesNo Type String The version of the compiled-in
zliblibrary. -
Command-Line Format --wait-timeout=#System Variable wait_timeoutScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Integer Default Value 28800Minimum Value 1Maximum Value (Windows) 2147483Maximum Value (Other) 31536000Unit seconds The number of seconds the server waits for activity on a noninteractive connection before closing it.
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 15.7.7.42, “SHOW WARNINGS Statement”.
-
Command-Line Format --windowing-use-high-precision[={OFF|ON}]System Variable windowing_use_high_precisionScope Global, Session Dynamic Yes SET_VARHint AppliesYes Type Boolean Default Value ONWhether to compute window operations without loss of precision. See Section 10.2.1.21, “Window Function Optimization”.
-
Command-Line Format --xa-detach-on-prepare[={OFF|ON}]System Variable xa_detach_on_prepareScope Global, Session Dynamic Yes SET_VARHint AppliesNo Type Boolean Default Value ONWhen set to
ON(enabled), all XA transactions are detached (disconnected) from the connection (session) as part ofXA PREPARE. This means that the XA transaction can be committed or rolled back by another connection, even if the originating connection has not terminated, and this connection can start new transactions.Temporary tables cannot be used inside detached XA transactions.
When this is
OFF(disabled), an XA transaction is strictly associated with the same connection until the session disconnects. It is recommended that you allow it to be enabled (the default behavior) for replication.For more information, see Section 15.3.8.2, “XA Transaction States”.