mysqld is the MySQL server. The following discussion covers these MySQL server configuration topics:
-
Startup options that the server supports
-
Server system variables
-
Server status variables
-
How to set the server SQL mode
-
The server shutdown process
When you start the mysqld server, you can specify program options using any of the methods described in Section 4.3, “Specifying Program Options”. The most common methods are to provide options in an option file or on the command line. However, in most cases it is desirable to make sure that the server uses the same options each time it runs. The best way to ensure this is to list them in an option file. See Section 4.3.2, “Using Option Files”.
mysqld reads options from the
[mysqld]
and [server]
groups. mysqld_safe reads options from the
[mysqld]
, [server]
,
[mysqld_safe]
, and
[safe_mysqld]
groups.
mysql.server reads options from the
[mysqld]
and
[mysql.server]
groups.
An embedded MySQL server usually reads options from the
[server]
, [embedded]
,
and
[
xxxxx
_SERVER]
groups, where xxxxx
is the name of
the application into which the server is embedded.
mysqld accepts many command options. For a brief summary, execute mysqld --help. To see the full list, use mysqld --verbose --help.
The following list shows some of the most common server options. Additional options are described in other sections:
-
Options that affect security: See Section 5.7.3, “Security-Related mysqld Options”.
-
SSL-related options: See Section 5.9.7.3, “SSL Command Options”.
-
Binary log control options: See Section 5.12.3, “The Binary Log”.
-
Replication-related options: See Section 6.8, “Replication Startup Options”.
-
Options specific to particular storage engines: See Section 14.1.1, “
MyISAM
Startup Options”, Section 14.5.3, “BDB
Startup Options”, Section 14.2.4, “InnoDB
Startup Options and System Variables”, and Section 15.6.5.1, “MySQL Cluster-Related Command Options for mysqld”.
You can also set the values of server system variables by using variable names as options, as described later in this section.
-
Display a short help message and exit. Use both the
--verbose
and--help
options to see the full message. -
This option controls whether user-defined functions that have only an
xxx
symbol for the main function can be loaded. By default, the option is off and only UDFs that have at least one auxiliary symbol can be loaded; this prevents attempts at loading functions from shared object files other than those containing legitimate UDFs. This option was added in version 5.0.3. See Section 24.2.4.6, “User-Defined Function Security Precautions”. -
Use standard (ANSI) SQL syntax instead of MySQL syntax. For more precise control over the server SQL mode, use the
--sql-mode
option instead. See Section 1.9.3, “Running MySQL in ANSI Mode”, and Section 5.2.5, “The Server SQL Mode”. -
The path to the MySQL installation directory. All paths are usually resolved relative to this directory.
-
The IP address to bind to.
-
This option is used by the mysql_install_db script to create the MySQL privilege tables without having to start a full MySQL server.
-
The directory where character sets are installed. See Section 5.11.1, “The Character Set Used for Data and Sorting”.
-
--character-set-client-handshake
Don't ignore character set information sent by the client. To ignore client information and use the default server character set, use
--skip-character-set-client-handshake
; this makes MySQL behave like MySQL 4.0. -
--character-set-filesystem=
charset_name
The filesystem character set. This option sets the
character_set_filesystem
system variable. It was added in MySQL 5.0.19. -
--character-set-server=
charset_name
,-C
charset_name
Use
charset_name
as the default server character set. See Section 5.11.1, “The Character Set Used for Data and Sorting”. -
Put the mysqld server in a closed environment during startup by using the
chroot()
system call. This is a recommended security measure. Note that use of this option somewhat limitsLOAD DATA INFILE
andSELECT ... INTO OUTFILE
. -
--collation-server=
collation_name
Use
collation_name
as the default server collation. See Section 5.11.1, “The Character Set Used for Data and Sorting”. -
(Windows only.) Write error log messages to
stderr
andstdout
even if--log-error
is specified. mysqld does not close the console window if this option is used. -
Write a core file if mysqld dies. For some systems, you must also specify the
--core-file-size
option to mysqld_safe. See Section 5.4.1, “mysqld_safe — MySQL Server Startup Script”. Note that on some systems, such as Solaris, you do not get a core file if you are also using the--user
option. -
The path to the data directory.
-
--debug[=
debug_options
],-# [
debug_options
]If MySQL is configured with
--with-debug
, you can use this option to get a trace file of what mysqld is doing. Thedebug_options
string often is'd:t:o,
file_name
'. The default is'd:t:i:o,mysqld.trace'
. See Section E.1.2, “Creating Trace Files”. -
--default-character-set=
charset_name
(DEPRECATED)Use
charset_name
as the default character set. This option is deprecated in favor of--character-set-server
. See Section 5.11.1, “The Character Set Used for Data and Sorting”. -
--default-collation=
collation_name
Use
collation_name
as the default collation. This option is deprecated in favor of--collation-server
. See Section 5.11.1, “The Character Set Used for Data and Sorting”. -
Set the default storage engine (table type) for tables. See Chapter 14, Storage Engines and Table Types.
-
This option is a synonym for
--default-storage-engine
. -
Set the default server time zone. This option sets the global
time_zone
system variable. If this option is not given, the default time zone is the same as the system time zone (given by the value of thesystem_time_zone
system variable. -
--delay-key-write[={OFF|ON|ALL}]
Specify how to use delayed key writes. Delayed key writing causes key buffers not to be flushed between writes for
MyISAM
tables.OFF
disables delayed key writes.ON
enables delayed key writes for those tables that were created with theDELAY_KEY_WRITE
option.ALL
delays key writes for allMyISAM
tables. See Section 7.5.2, “Tuning Server Parameters”, and Section 14.1.1, “MyISAM
Startup Options”.Note: If you set this variable to
ALL
, you should not useMyISAM
tables from within another program (such as another MySQL server or myisamchk) when the tables are in use. Doing so leads to index corruption. -
Read the default DES keys from this file. These keys are used by the
DES_ENCRYPT()
andDES_DECRYPT()
functions. -
Enable support for named pipes. This option applies only on Windows NT, 2000, XP, and 2003 systems, and can be used only with the mysqld-nt and mysqld-max-nt servers that support named-pipe connections.
-
--exit-info[=
flags
],-T [
flags
]This is a bit mask of different flags that you can use for debugging the mysqld server. Do not use this option unless you know exactly what it does!
-
Enable external locking (system locking), which is disabled by default as of MySQL 4.0. Note that if you use this option on a system on which
lockd
does not fully work (such as Linux), it is easy for mysqld to deadlock. This option previously was named--enable-locking
.Note: If you use this option to enable updates to
MyISAM
tables from many MySQL processes, you must ensure that the following conditions are satisfied:-
You should not use the query cache for queries that use tables that are updated by another process.
-
You should not use
--delay-key-write=ALL
orDELAY_KEY_WRITE=1
on any shared tables.
The easiest way to ensure this is to always use
--external-locking
together with--delay-key-write=OFF
and--query-cache-size=0
. (This is not done by default because in many setups it is useful to have a mixture of the preceding options.) -
-
Flush (synchronize) 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 A.4.2, “What to Do If MySQL Keeps Crashing”.
-
Read SQL statements from this file at startup. Each statement must be on a single line and should not include comments.
-
Adds consistency guarantees between the content of
InnoDB
tables and the binary log. See Section 5.12.3, “The Binary Log”. This option was removed in MySQL 5.0.3, having been made obsolete by the introduction of XA transaction support. -
--innodb-
xxx
The
InnoDB
options are listed in Section 14.2.4, “InnoDB
Startup Options and System Variables”. -
--language=
lang_name
, -Llang_name
Return client error messages in the given language.
lang_name
can be given as the language name or as the full pathname to the directory where the language files are installed. See Section 5.11.2, “Setting the Error Message Language”. -
Some hardware/operating system architectures support memory pages greater than the default (usually 4KB). The actual implementation of this support depends on the underlying hardware and OS. Applications that perform a lot of memory accesses may obtain performance improvements by using large pages due to reduced Translation Lookaside Buffer (TLB) misses.
Currently, MySQL supports only the Linux implementation of large pages support (which is called HugeTLB in Linux). We have plans to extend this support to FreeBSD, Solaris and possibly other platforms.
Before large pages can be used on Linux, it is necessary to configure the HugeTLB memory pool. For reference, consult the
hugetlbpage.txt
file in the Linux kernel source.This option is disabled by default. It was added in MySQL 5.0.3.
-
--log[=
file_name
],-l [
file_name
]Log connections and SQL statements received from clients to this file. See Section 5.12.2, “The General Query Log”. If you omit the filename, MySQL uses
host_name
.log as the filename. -
Enable binary logging. The server logs all statements that change data to the binary log, which is used for backup and replication. See Section 5.12.3, “The Binary Log”.
The option value, if given, is the basename for the log sequence. The server creates binary log files in sequence by adding a numeric suffix to the basename. It is recommended that you specify a basename (see Section A.8.1, “Open Issues in MySQL”, for the reason). Otherwise, MySQL uses
host_name
-bin as the basename. -
The index file for binary log filenames. See Section 5.12.3, “The Binary Log”. If you omit the filename, and if you didn't specify one with
--log-bin
, MySQL useshost_name
-bin.index as the filename. -
--log-bin-trust-function-creators[={0|1}]
With no argument or an argument of 1, this option sets the
log_bin_trust_function_creators
system variable to 1. With an argument of 0, this option sets the system variable to 0.log_bin_trust_function_creators
affects how MySQL enforces restrictions on stored function creation. See Section 17.4, “Binary Logging of Stored Routines and Triggers”.This option was added in MySQL 5.0.16.
-
--log-bin-trust-routine-creators[={0|1}]
This is the old name for
--log-bin-trust-function-creators
. Before MySQL 5.0.16, it also applies to stored procedures, not just stored functions and sets thelog_bin_trust_routine_creators
system variable. As of 5.0.16, this option is deprecated. It is recognized for backward compatibility but its use results in a warning.This option was added in MySQL 5.0.6.
-
Log errors and startup messages to this file. See Section 5.12.1, “The Error Log”. If you omit the filename, MySQL uses
host_name
.err. If the filename has no extension, the server adds an extension of.err
. -
Log all
MyISAM
changes to this file (used only when debuggingMyISAM
). -
--log-long-format
(DEPRECATED)Log extra information to the update log, binary update log, and slow query log, if they have been activated. For example, the username and timestamp are logged for all queries. This option is deprecated, as it now represents the default logging behavior. (See the description for
--log-short-format
.) The--log-queries-not-using-indexes
option is available for the purpose of logging queries that do not use indexes to the slow query log. -
--log-queries-not-using-indexes
If you are using this option with
--log-slow-queries
, queries that do not use indexes are logged to the slow query log. See Section 5.12.4, “The Slow Query Log”. -
Log less information to the update log, binary update log, and slow query log, if they have been activated. For example, the username and timestamp are not logged for queries.
-
Log slow administrative statements such as
OPTIMIZE TABLE
,ANALYZE TABLE
, andALTER TABLE
to the slow query log. -
--log-slow-queries[=
file_name
]Log all queries that have taken more than
long_query_time
seconds to execute to this file. See Section 5.12.4, “The Slow Query Log”. See the descriptions of the--log-long-format
and--log-short-format
options for details. -
--log-warnings[=
level
],-W [
level
]Print out warnings such as
Aborted connection...
to the error log. Enabling this option is recommended, for example, if you use replication (you get more information about what is happening, such as messages about network failures and reconnections). This option is enabled (1) by default, and the defaultlevel
value if omitted is 1. To disable this option, use--log-warnings=0
. Aborted connections are not logged to the error log unless the value is greater than 1. See Section A.2.10, “Communication Errors and Aborted Connections”. -
Give table-modifying operations (
INSERT
,REPLACE
,DELETE
,UPDATE
) lower priority than selects. This can also be done via{INSERT | REPLACE | DELETE | UPDATE} LOW_PRIORITY ...
to lower the priority of only one query, or bySET LOW_PRIORITY_UPDATES=1
to change the priority in one thread. See Section 7.3.2, “Table Locking Issues”. -
Lock the mysqld process in memory. This works on systems such as Solaris that support the
mlockall()
system call. This might help if you have a problem where the operating system is causing mysqld to swap on disk. Note that use of this option requires that you run the server asroot
, which is normally not a good idea for security reasons. See Section 5.7.5, “How to Run MySQL as a Normal User”. -
--myisam-recover[=
option
[,option
]...]]Set the
MyISAM
storage engine recovery mode. The option value is any combination of the values ofDEFAULT
,BACKUP
,FORCE
, orQUICK
. If you specify multiple values, separate them by commas. You can also use a value of""
to disable this option. If this option is used, each time mysqld opens aMyISAM
table, it checks whether the table is marked as crashed or wasn't 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 DEFAULT
The same as not giving any option to --myisam-recover
.BACKUP
If the data file was changed during recovery, save a backup of the tbl_name
.MYD file astbl_name-datetime
.BAK.FORCE
Run recovery even if we would lose more than one row from the .MYD
file.QUICK
Don't check the rows in the table if there aren't 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. -
--ndb-connectstring=
connect_string
When using the
NDB
storage engine, it is possible to point out the management server that distributes the cluster configuration by setting the connect string option. See Section 15.4.4.2, “The Clusterconnectstring
”, for syntax. -
If the binary includes support for the
NDB Cluster
storage engine, this option enables the engine, which is disabled by default. See Chapter 15, MySQL Cluster. -
Force the server to generate short (pre-4.1) password hashes for new passwords. This is useful for compatibility when the server must support older client programs. See Section 5.8.9, “Password Hashing as of MySQL 4.1”.
-
Only use one thread (for debugging under Linux). This option is available only if the server is built with debugging enabled. See Section E.1, “Debugging a MySQL Server”.
-
Change the number of file descriptors available to mysqld. If this option is not set or is set to 0, mysqld uses the value to reserve file descriptors with
setrlimit()
. If the value is 0, mysqld reservesmax_connections×5
ormax_connections + table_open_cache×2
files (whichever is larger). You should try increasing this value if mysqld gives you the errorToo many open files
. -
The pathname of the process ID file. This file is used by other programs such as mysqld_safe to determine the server's process ID.
-
The port number to use when listening for TCP/IP connections. The port number must be 1024 or higher unless the server is started by the
root
system user. -
On some systems, when the server is stopped, the TCP/IP port might not become available immediately. If the server is restarted quickly afterward, its attempt to reopen the port can fail. This option indicates how many seconds the server should wait for the TCP/IP port to become free if it cannot be opened. The default is not to wait. This option was added in MySQL 5.0.19.
-
Skip some optimization stages.
-
If this option is enabled, a user cannot create new MySQL users by using the
GRANT
statement, if the user doesn't have theINSERT
privilege for themysql.user
table or any column in the table. -
Disallow authentication by clients that attempt to use accounts that have old (pre-4.1) passwords.
-
Enable shared-memory connections by local clients. This option is available only on Windows.
-
--shared-memory-base-name=
name
The name of shared memory to use for shared-memory connections. This option is available only on Windows. The default name is
MYSQL
. The name is case sensitive. -
Disable the
BDB
storage engine. This saves memory and might speed up some operations. Do not use this option if you requireBDB
tables. -
Turn off the ability to select and insert at the same time on
MyISAM
tables. (This is to be used only if you think you have found a bug in this feature.) See Section 7.3.3, “Concurrent Inserts”. -
Do not use external locking (system locking). With external locking disabled, you must shut down the server to use myisamchk. (See Section 1.4.3, “MySQL Stability”.) To avoid this requirement, use the
CHECK TABLE
andREPAIR TABLE
statements to check and repairMyISAM
tables.External locking has been disabled by default since MySQL 4.0.
-
This option causes the server not to use the privilege system at all, which gives anyone with access to the server unrestricted access to all databases. You can cause a running server to start using the grant tables again by executing mysqladmin flush-privileges or mysqladmin reload command from a system shell, or by issuing a MySQL
FLUSH PRIVILEGES
statement after connecting to the server. This option also suppresses loading of user-defined functions (UDFs). -
Do not use the internal hostname cache for faster name-to-IP resolution. Instead, query the DNS server every time a client connects. See Section 7.5.6, “How MySQL Uses DNS”.
-
Disable the
InnoDB
storage engine. This saves memory and disk space and might speed up some operations. Do not use this option if you requireInnoDB
tables. -
Disable the
MERGE
storage engine. This option was added in MySQL 5.0.24. It can be used if the following behavior is undesirable: If a user has access toMyISAM
tablet
, that user can create aMERGE
tablem
that accessest
. However, if the user's privileges ont
are subsequently revoked, the user can continue to accesst
by doing so throughm
. -
Do not resolve hostnames when checking client connections. Use only IP numbers. If you use this option, all
Host
column values in the grant tables must be IP numbers orlocalhost
. See Section 7.5.6, “How MySQL Uses DNS”. -
Disable the
NDB Cluster
storage engine. This is the default for binaries that were built withNDB Cluster
storage engine support; the server allocates memory and other resources for this storage engine only if the--ndbcluster
option is given explicitly. See Section 15.4.3, “Quick Test Setup of MySQL Cluster”, for an example of usage. -
Don't listen for TCP/IP connections at all. All interaction with mysqld must be made via 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 allowed. See Section 7.5.6, “How MySQL Uses DNS”.
-
Options that begin with
--ssl
specify whether to allow clients to connect via SSL and indicate where to find SSL keys and certificates. See Section 5.9.7.3, “SSL Command Options”. -
Available on Windows NT-based systems only; instructs the MySQL server not to run as a service.
-
--symbolic-links
,--skip-symbolic-links
Enable or disable symbolic link support. This option has different effects on Windows and Unix:
-
On Windows, enabling symbolic links allows you to establish a symbolic link to a database directory by creating a
db_name
.sym file that contains the path to the real directory. See Section 7.6.1.3, “Using Symbolic Links for Databases on Windows”. -
On Unix, enabling symbolic links means that you can link a
MyISAM
index file or data file to another directory with theINDEX DIRECTORY
orDATA DIRECTORY
options of theCREATE TABLE
statement. If you delete or rename the table, the files that its symbolic links point to also are deleted or renamed. See Section 7.6.1.2, “Using Symbolic Links for Tables on Unix”.
-
-
If MySQL is configured with
--with-debug=full
, all MySQL programs check for memory overruns during each memory allocation and memory freeing operation. This checking is very slow, so for the server you can avoid it when you don't need it by using the--skip-safemalloc
option. -
With this option, the
SHOW DATABASES
statement is allowed only to users who have theSHOW DATABASES
privilege, and the statement displays all database names. Without this option,SHOW DATABASES
is allowed to all users, but displays each database name only if the user has theSHOW DATABASES
privilege or some privilege for the database. Note that any global privilege is considered a privilege for the database. -
Don't write stack traces. This option is useful when you are running mysqld under a debugger. On some systems, you also must use this option to get a core file. See Section E.1, “Debugging a MySQL Server”.
-
Disable using thread priorities for faster response time.
-
On Unix, this option specifies the Unix socket file to use when listening for local connections. The default value is
/tmp/mysql.sock
. On Windows, the option specifies the pipe name to use when listening for local connections that use a named pipe. The default value isMySQL
(not case sensitive). -
--sql-mode=
value
[,value
[,value
...]]Set the SQL mode. See Section 5.2.5, “The Server SQL Mode”.
-
As of MySQL 5.0.13,
SYSDATE()
by default returns the time at which it executes, not the time at which the statement in which it occurs begins executing. This differs from the behavior ofNOW()
. This option causesSYSDATE()
to be an alias forNOW()
. For information about the implications for binary logging and replication, see the description forSYSDATE()
in Section 12.5, “Date and Time Functions” and forSET TIMESTAMP
in Section 13.5.3, “SET
Syntax”.This option was added in MySQL 5.0.20.
-
This option causes most temporary files created by the server to use a small set of names, rather than a unique name for each new file. This works around a problem in the Linux kernel dealing with creating many new files with different names. With the old behavior, Linux seems to “leak” memory, because it is being allocated to the directory entry cache rather than to the disk cache.
-
Sets the default transaction isolation level. The
level
value can beREAD-UNCOMMITTED
,READ-COMMITTED
,REPEATABLE-READ
, orSERIALIZABLE
. See Section 13.4.6, “SET TRANSACTION
Syntax”. -
The path of the directory to use for creating temporary files. It might be useful if your default
/tmp
directory resides on a partition that is too small to hold temporary tables. This option accepts several paths that are used in round-robin fashion. Paths should be separated by colon characters (‘:
’) on Unix and semicolon characters (‘;
’) on Windows, NetWare, and OS/2. If the MySQL server is acting as a replication slave, you should not set--tmpdir
to point to a directory on a memory-based filesystem or to a directory that is cleared when the server host restarts. For more information about the storage location of temporary files, see Section A.4.4, “Where MySQL Stores Temporary Files”. A replication slave needs some of its temporary files to survive a machine restart so that it can replicate temporary tables orLOAD DATA INFILE
operations. If files in the temporary file directory are lost when the server restarts, replication fails. -
--user={
user_name
|user_id
},-u {
user_name
|user_id
}Run the mysqld server as the user having the name
user_name
or the numeric user IDuser_id
. (“User” in this context refers to a system login account, not a MySQL user listed in the grant tables.)This option is mandatory when starting mysqld as
root
. The server changes its user ID during its startup sequence, causing it to run as that particular user rather than asroot
. See Section 5.7.1, “General Security Guidelines”.To avoid a possible security hole where a user adds a
--user=root
option to amy.cnf
file (thus causing the server to run asroot
), mysqld uses only the first--user
option specified and produces a warning if there are multiple--user
options. Options in/etc/my.cnf
and$MYSQL_HOME/my.cnf
are processed before command-line options, so it is recommended that you put a--user
option in/etc/my.cnf
and specify a value other thanroot
. The option in/etc/my.cnf
is found before any other--user
options, which ensures that the server runs as a user other thanroot
, and that a warning results if any other--user
option is found. -
Display version information and exit.
You can assign a value to a server system variable by using an
option of the form
--
var_name
=value
.
For example, --key_buffer_size=32M
sets the
key_buffer_size
variable to a value of
32MB.
Note that when you assign a value to a variable, MySQL might automatically correct the value to stay within a given range, or adjust the value to the closest allowable value if only certain values are allowed.
If you want to restrict the maximum value to which a variable
can be set at runtime with SET
, you can
define this by using the
--maximum-
var_name
=value
command-line option.
It is also possible to set variables by using
--set-variable=
var_name
=value
or -O
var_name
=value
syntax. This syntax is deprecated.
You can change the values of most system variables for a
running server with the SET
statement. See
Section 13.5.3, “SET
Syntax”.
Section 5.2.2, “Server System Variables”, provides a full description for all variables, and additional information for setting them at server startup and runtime. Section 7.5.2, “Tuning Server Parameters”, includes information on optimizing the server by tuning system variables.
The mysql server maintains many system
variables that indicate how it is configured. Each system
variable has a default value. System variables can be set at
server startup using options on the command line or in an
option file. Most of them can be changed dynamically while the
server is running by means of the SET
statement, which enables you to modify operation of the server
without having to stop and restart it. You can refer to system
variable values in expressions.
There are several ways to see the names and values of system variables:
-
To see the values that a server will use based on its compiled-in defaults and any option files that it reads, use this command:
mysqld --verbose --help
-
To see the values that a server will use based on its compiled-in defaults, ignoring the settings in any option files, use this command:
mysqld --no-defaults --verbose --help
-
To see the current values used by a running server, use the
SHOW VARIABLES
statement.
This section provides a description of each system variable. Variables with no version indicated are present in all MySQL 5.0 releases. For historical information concerning their implementation, please see MySQL 3.23, 4.0, 4.1 Reference Manual.
For additional system variable information, see these sections:
-
Section 5.2.3, “Using System Variables”, discusses the syntax for setting and displaying system variable values.
-
Section 5.2.3.2, “Dynamic System Variables”, lists the variables that can be set at runtime.
-
Information on tuning sytem variables can be found in Section 7.5.2, “Tuning Server Parameters”.
-
Section 14.2.4, “
InnoDB
Startup Options and System Variables”, listsInnoDB
system variables.
Note: Some of the following variable
descriptions refer to “enabling” or
“disabling” a variable. These variables can be
enabled with the SET
statement by setting
them to ON
or 1
, or
disabled by setting them to OFF
or
0
. However, to set such a variable on the
command line or in an option file, you must set it to
1
or 0
; setting it to
ON
or OFF
will not work.
For example, on the command line,
--delay_key_write=1
works but
--delay_key_write=ON
does not.
Values for buffer sizes, lengths, and stack sizes are given in bytes unless otherwise specified.
-
auto_increment_increment
auto_increment_increment
andauto_increment_offset
are intended for use with master-to-master replication, and can be used to control the operation ofAUTO_INCREMENT
columns. Both variables can be set globally or locally, and each can assume an integer value between 1 and 65,535 inclusive. Setting the value of either of these two variables to 0 causes its value to be set to 1 instead. Attempting to set the value of either of these two variables to an integer greater than 65,535 or less than 0 causes its value to be set to 65,535 instead. Attempting to set the value ofauto_increment_increment
orauto_increment_offset
to a non-integer value gives rise to an error, and the actual value of the variable remains unchanged.These two variables affect
AUTO_INCREMENT
column behavior as follows:-
auto_increment_increment
controls the interval between successive column values. For example:mysql>
SHOW VARIABLES LIKE 'auto_inc%';
+--------------------------+-------+ | Variable_name | Value | +--------------------------+-------+ | auto_increment_increment | 1 | | auto_increment_offset | 1 | +--------------------------+-------+ 2 rows in set (0.00 sec) mysql>CREATE TABLE autoinc1
->(col INT NOT NULL AUTO_INCREMENT PRIMARY KEY);
Query OK, 0 rows affected (0.04 sec) mysql>SET @@auto_increment_increment=10;
Query OK, 0 rows affected (0.00 sec) mysql>SHOW VARIABLES LIKE 'auto_inc%';
+--------------------------+-------+ | Variable_name | Value | +--------------------------+-------+ | auto_increment_increment | 10 | | auto_increment_offset | 1 | +--------------------------+-------+ 2 rows in set (0.01 sec) mysql>INSERT INTO autoinc1 VALUES (NULL), (NULL), (NULL), (NULL);
Query OK, 4 rows affected (0.00 sec) Records: 4 Duplicates: 0 Warnings: 0 mysql>SELECT col FROM autoinc1;
+-----+ | col | +-----+ | 1 | | 11 | | 21 | | 31 | +-----+ 4 rows in set (0.00 sec)(Note how
SHOW VARIABLES
is used here to obtain the current values for these variables.) -
auto_increment_offset
determines the starting point for theAUTO_INCREMENT
column value. Consider the following, assuming that these statements are executed during the same session as the example given in the description forauto_increment_increment
:mysql>
SET @@auto_increment_offset=5;
Query OK, 0 rows affected (0.00 sec) mysql>SHOW VARIABLES LIKE 'auto_inc%';
+--------------------------+-------+ | Variable_name | Value | +--------------------------+-------+ | auto_increment_increment | 10 | | auto_increment_offset | 5 | +--------------------------+-------+ 2 rows in set (0.00 sec) mysql>CREATE TABLE autoinc2
->(col INT NOT NULL AUTO_INCREMENT PRIMARY KEY);
Query OK, 0 rows affected (0.06 sec) mysql>INSERT INTO autoinc2 VALUES (NULL), (NULL), (NULL), (NULL);
Query OK, 4 rows affected (0.00 sec) Records: 4 Duplicates: 0 Warnings: 0 mysql>SELECT col FROM autoinc2;
+-----+ | col | +-----+ | 5 | | 15 | | 25 | | 35 | +-----+ 4 rows in set (0.02 sec)If the value of
auto_increment_offset
is greater than that ofauto_increment_increment
, the value ofauto_increment_offset
is ignored.
Should one or both of these variables be changed and then new rows inserted into a table containing an
AUTO_INCREMENT
column, the results may seem counterintuitive because the series ofAUTO_INCREMENT
values is calculated without regard to any values already present in the column, and the next value inserted is the least value in the series that is greater than the maximum existing value in theAUTO_INCREMENT
column. In other words, the series is calculated like so:auto_increment_offset +
N
× auto_increment_incrementwhere
N
is a positive integer value in the series [1, 2, 3, ...]. For example:mysql>
SHOW VARIABLES LIKE 'auto_inc%';
+--------------------------+-------+ | Variable_name | Value | +--------------------------+-------+ | auto_increment_increment | 10 | | auto_increment_offset | 5 | +--------------------------+-------+ 2 rows in set (0.00 sec) mysql>SELECT col FROM autoinc1;
+-----+ | col | +-----+ | 1 | | 11 | | 21 | | 31 | +-----+ 4 rows in set (0.00 sec) mysql>INSERT INTO autoinc1 VALUES (NULL), (NULL), (NULL), (NULL);
Query OK, 4 rows affected (0.00 sec) Records: 4 Duplicates: 0 Warnings: 0 mysql>SELECT col FROM autoinc1;
+-----+ | col | +-----+ | 1 | | 11 | | 21 | | 31 | | 35 | | 45 | | 55 | | 65 | +-----+ 8 rows in set (0.00 sec)The values shown for
auto_increment_increment
andauto_increment_offset
generate the series 5 +N
× 10, that is, [5, 15, 25, 35, 45, ...]. The greatest value present in thecol
column prior to theINSERT
is 31, and the next available value in theAUTO_INCREMENT
series is 35, so the inserted values forcol
begin at that point and the results are as shown for theSELECT
query.It is important to remember that it is not possible to confine the effects of these two variables to a single table, and thus they do not take the place of the sequences offered by some other database management systems; these variables control the behavior of all
AUTO_INCREMENT
columns in all tables on the MySQL server. If one of these variables is set globally, its effects persist until the global value is changed or overridden by setting them locally, or until mysqld is restarted. If set locally, the new value affectsAUTO_INCREMENT
columns for all tables into which new rows are inserted by the current user for the duration of the session, unless the values are changed during that session.The
auto_increment_increment
variable was added in MySQL 5.0.2. Its default value is 1. See Section 6.13, “Auto-Increment in Multiple-Master Replication”. -
-
auto_increment_offset
This variable was introduced in MySQL 5.0.2. Its default value is 1. For particulars, see the description for
auto_increment_increment
. -
back_log
The number of outstanding connection requests MySQL can have. This comes into play when the main MySQL thread gets very many connection requests in a very short time. It then takes some time (although very little) for the main thread to check the connection and start a new thread. The
back_log
value indicates how many requests can be stacked during this short time before MySQL momentarily stops answering new requests. You need to increase this only if you expect a large number of connections in a short period of time.In other words, this value is the size of the listen queue for incoming TCP/IP connections. Your operating system has its own limit on the size of this queue. The manual page for the Unix
listen()
system call should have more details. Check your OS documentation for the maximum value for this variable.back_log
cannot be set higher than your operating system limit. -
basedir
The MySQL installation base directory. This variable can be set with the
--basedir
option. -
bdb_cache_size
The size of the buffer that is allocated for caching indexes and rows for
BDB
tables. If you don't useBDB
tables, you should start mysqld with--skip-bdb
to not allocate memory for this cache. -
bdb_home
The base directory for
BDB
tables. This should be assigned the same value as thedatadir
variable. -
bdb_log_buffer_size
The size of the buffer that is allocated for caching indexes and rows for
BDB
tables. If you don't useBDB
tables, you should set this to 0 or start mysqld with--skip-bdb
to not allocate memory for this cache. -
bdb_logdir
The directory where the
BDB
storage engine writes its log files. This variable can be set with the--bdb-logdir
option. -
bdb_max_lock
The maximum number of locks that can be active for a
BDB
table (10,000 by default). You should increase this value if errors such as the following occur when you perform long transactions or when mysqld has to examine many rows to calculate a query:bdb: Lock table is out of available locks Got error 12 from ...
-
bdb_shared_data
This is
ON
if you are using--bdb-shared-data
to start Berkeley DB in multi-process mode. (Do not useDB_PRIVATE
when initializing Berkeley DB.) -
bdb_tmpdir
The
BDB
temporary file directory. -
binlog_cache_size
The size of the cache to hold the SQL statements for the binary log during a transaction. A binary log cache is allocated for each client if the server supports any transactional storage engines and if the server has the binary log enabled (
--log-bin
option). If you often use large, multiple-statement transactions, you can increase this cache size to get more performance. TheBinlog_cache_use
andBinlog_cache_disk_use
status variables can be useful for tuning the size of this variable. See Section 5.12.3, “The Binary Log”. -
bulk_insert_buffer_size
MyISAM
uses a special tree-like cache to make bulk inserts faster forINSERT ... SELECT
,INSERT ... VALUES (...), (...), ...
, andLOAD DATA INFILE
when adding data to non-empty tables. This variable limits the size of the cache tree in bytes per thread. Setting it to 0 disables this optimization. The default value is 8MB. -
character_set_client
The character set for statements that arrive from the client.
-
character_set_connection
The character set used for literals that do not have a character set introducer and for number-to-string conversion.
-
character_set_database
The character set used by the default database. The server sets this variable whenever the default database changes. If there is no default database, the variable has the same value as
character_set_server
. -
character_set_filesystem
The filesystem character set. This variable is used to interpret string literals that refer to filenames, such as in the
LOAD DATA INFILE
andSELECT ... INTO OUTFILE
statements and theLOAD_FILE()
function. Such filenames are converted fromcharacter_set_client
tocharacter_set_filesystem
before the file opening attempt occurs. The default value isbinary
, which means that no conversion occurs. For systems on which multi-byte filenames are allowed, a different value may be more appropriate. For example, if the system represents filenames using UTF-8, setcharacter_set_filesytem
to'utf8'
. This variable was added in MySQL 5.0.19. -
character_set_results
The character set used for returning query results to the client.
-
character_set_server
The server's default character set.
-
character_set_system
The character set used by the server for storing identifiers. The value is always
utf8
. -
character_sets_dir
The directory where character sets are installed.
-
collation_connection
The collation of the connection character set.
-
collation_database
The collation used by the default database. The server sets this variable whenever the default database changes. If there is no default database, the variable has the same value as
collation_server
. -
collation_server
The server's default collation.
-
completion_type
The transaction completion type:
-
If the value is 0 (the default),
COMMIT
andROLLBACK
are unaffected. -
If the value is 1,
COMMIT
andROLLBACK
are equivalent toCOMMIT AND CHAIN
andROLLBACK AND CHAIN
, respectively. (A new transaction starts immediately with the same isolation level as the just-terminated transaction.) -
If the value is 2,
COMMIT
andROLLBACK
are equivalent toCOMMIT RELEASE
andROLLBACK RELEASE
, respectively. (The server disconnects after terminating the transaction.)
This variable was added in MySQL 5.0.3
-
-
concurrent_insert
If
ON
(the default), MySQL allowsINSERT
andSELECT
statements to run concurrently forMyISAM
tables that have no free blocks in the middle. You can turn this option off by starting mysqld with--safe
or--skip-new
.In MySQL 5.0.6, this variable was changed to take three integer values:
Value Description 0 Off 1 (Default) Enables concurrent insert for MyISAM
tables that don't have holes2 Enables concurrent inserts for all MyISAM
tables. If table has a hole and is in use by another thread the new row will be inserted at end of table. If table is not in use, MySQL does a normal read lock and inserts the new row into the hole.See also Section 7.3.3, “Concurrent Inserts”.
-
The number of seconds that the mysqld server waits for a connect packet before responding with
Bad handshake
. -
datadir
The MySQL data directory. This variable can be set with the
--datadir
option. -
date_format
This variable is not implemented.
-
datetime_format
This variable is not implemented.
-
default_week_format
The default mode value to use for the
WEEK()
function. See Section 12.5, “Date and Time Functions”. -
delay_key_write
This option applies only to
MyISAM
tables. It can have one of the following values to affect handling of theDELAY_KEY_WRITE
table option that can be used inCREATE TABLE
statements.Option Description OFF
DELAY_KEY_WRITE
is ignored.ON
MySQL honors any DELAY_KEY_WRITE
option specified inCREATE TABLE
statements. This is the default value.ALL
All new opened tables are treated as if they were created with the DELAY_KEY_WRITE
option enabled.If
DELAY_KEY_WRITE
is enabled for a table, the key buffer is not flushed for the table on every index update, but only when the table is closed. This speeds up writes on keys a lot, but if you use this feature, you should add automatic checking of allMyISAM
tables by starting the server with the--myisam-recover
option (for example,--myisam-recover=BACKUP,FORCE
). See Section 5.2.1, “mysqld Command Options”, and Section 14.1.1, “MyISAM
Startup Options”.Note that enabling external locking with
--external-locking
offers no protection against index corruption for tables that use delayed key writes. -
delayed_insert_limit
After inserting
delayed_insert_limit
delayed rows, theINSERT DELAYED
handler thread checks whether there are anySELECT
statements pending. If so, it allows them to execute before continuing to insert delayed rows. -
delayed_insert_timeout
How many seconds an
INSERT DELAYED
handler thread should wait forINSERT
statements before terminating. -
delayed_queue_size
This is a per-table limit on the number of rows to queue when handling
INSERT DELAYED
statements. If the queue becomes full, any client that issues anINSERT DELAYED
statement waits until there is room in the queue again. -
div_precision_increment
This variable indicates the number of digits of precision by which to increase the result of division operations performed with the
/
operator. The default value is 4. The minimum and maximum values are 0 and 30, respectively. The following example illustrates the effect of increasing the default value.mysql>
SELECT 1/7;
+--------+ | 1/7 | +--------+ | 0.1429 | +--------+ mysql>SET div_precision_increment = 12;
mysql>SELECT 1/7;
+----------------+ | 1/7 | +----------------+ | 0.142857142857 | +----------------+This variable was added in MySQL 5.0.6.
-
engine_condition_pushdown
This variable applies to NDB. By default it is 0 (
OFF
): If you execute a query such asSELECT * FROM t WHERE mycol = 42
, wheremycol
is a non-indexed column, the query is executed as a full table scan on every NDB node. Each node sends every row to the MySQL server, which applies theWHERE
condition. Ifengine_condition_pushdown
is set to 1 (ON
), the condition is “pushed down” to the storage engine and sent to the NDB nodes. Each node uses the condition to perform the scan, and only sends back to the MySQL server the rows that match the condition.This variable was added in MySQL 5.0.3. Before that, the default
NDB
behavior is the same as for a value ofOFF
. -
expire_logs_days
The number of days for automatic binary log removal. The default is 0, which means “no automatic removal.” Possible removals happen at startup and at binary log rotation.
-
flush
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 A.4.2, “What to Do If MySQL Keeps Crashing”. This variable is set toON
if you start mysqld with the--flush
option. -
flush_time
If this is set to a non-zero value, all tables are closed every
flush_time
seconds to free up resources and synchronize unflushed data to disk. We recommend that this option be used only on Windows 9x or Me, or on systems with minimal resources. -
ft_boolean_syntax
The list of operators supported by boolean full-text searches performed using
IN BOOLEAN MODE
. See Section 12.7.1, “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 non-alphanumeric character.
-
Either the first or second character must be a space.
-
No duplicates are allowed except the phrase quoting operators in positions 11 and 12. These two characters are not required to be the same, but they are the only two that may be.
-
Positions 10, 13, and 14 (which by default are set to ‘
:
’, ‘&
’, and ‘|
’) are reserved for future extensions.
-
-
ft_max_word_len
The maximum length of the word to be included in a
FULLTEXT
index.Note:
FULLTEXT
indexes must be rebuilt after changing this variable. UseREPAIR TABLE
tbl_name
QUICK. -
ft_min_word_len
The minimum length of the word to be included in a
FULLTEXT
index.Note:
FULLTEXT
indexes must be rebuilt after changing this variable. UseREPAIR TABLE
tbl_name
QUICK. -
ft_query_expansion_limit
The number of top matches to use for full-text searches performed using
WITH QUERY EXPANSION
. -
ft_stopword_file
The file from which to read the list of stopwords for full-text searches. All the words from the file are used; comments are not honored. By default, a built-in list of stopwords is used (as defined in the
myisam/ft_static.c
file). Setting this variable to the empty string (''
) disables stopword filtering.Note:
FULLTEXT
indexes must be rebuilt after changing this variable or the contents of the stopword file. UseREPAIR TABLE
tbl_name
QUICK. -
group_concat_max_len
The maximum allowed result length for the
GROUP_CONCAT()
function. The default is 1024. -
have_archive
YES
if mysqld supportsARCHIVE
tables,NO
if not. -
have_bdb
YES
if mysqld supportsBDB
tables.DISABLED
if--skip-bdb
is used. -
have_blackhole_engine
YES
if mysqld supportsBLACKHOLE
tables,NO
if not. -
have_compress
YES
if thezlib
compression library is available to the server,NO
if not. If not, theCOMPRESS()
andUNCOMPRESS()
functions cannot be used. -
have_crypt
YES
if thecrypt()
system call is available to the server,NO
if not. If not, theENCRYPT()
function cannot be used. -
have_csv
YES
if mysqld supportsARCHIVE
tables,NO
if not. -
have_example_engine
YES
if mysqld supportsEXAMPLE
tables,NO
if not.have_federated_engine
YES
if mysqld supportsFEDERATED
tables,NO
if not. This variable was added in MySQL 5.0.3. -
have_geometry
YES
if the server supports spatial data types,NO
if not. -
have_innodb
YES
if mysqld supportsInnoDB
tables.DISABLED
if--skip-innodb
is used. -
have_isam
In MySQL 5.0, this variable appears only for reasons of backward compatibility. It is always
NO
becauseISAM
tables are no longer supported. -
have_ndbcluster
YES
if mysqld supportsNDB Cluster
tables.DISABLED
if--skip-ndbcluster
is used. -
have_openssl
YES
if mysqld supports SSL connections,NO
if not. -
have_query_cache
YES
if mysqld supports the query cache,NO
if not. -
have_raid
In MySQL 5.0, this variable appears only for reasons of backward compatibility. It is always
NO
becauseRAID
tables are no longer supported. -
have_rtree_keys
YES
ifRTREE
indexes are available,NO
if not. (These are used for spatial indexes inMyISAM
tables.) -
have_symlink
YES
if symbolic link support is enabled,NO
if not. This is required on Unix for support of theDATA DIRECTORY
andINDEX DIRECTORY
table options, and on Windows for support of data directory symlinks. -
init_connect
A string to be executed by the server for each client that connects. The string consists of one or more SQL statements. To specify multiple statements, separate them by semicolon characters. For example, each client begins by default with autocommit mode enabled. There is no global system variable to specify that autocommit should be disabled by default, but
init_connect
can be used to achieve the same effect:SET GLOBAL init_connect='SET AUTOCOMMIT=0';
This variable can also be set on the command line or in an option file. To set the variable as just shown using an option file, include these lines:
[mysqld] init_connect='SET AUTOCOMMIT=0'
Note that the content of
init_connect
is not executed for users that have theSUPER
privilege. This is done so that an erroneous value forinit_connect
does not prevent all clients from connecting. For example, the value might contain a statement that has a syntax error, thus causing client connections to fail. Not executinginit_connect
for users that have theSUPER
privilege enables them to open a connection and fix theinit_connect
value. -
init_file
The name of the file specified with the
--init-file
option when you start the server. This should be a file containing SQL statements that you want the server to execute when it starts. Each statement must be on a single line and should not include comments. -
init_slave
This variable is similar to
init_connect
, but is a string to be executed by a slave server each time the SQL thread starts. The format of the string is the same as for theinit_connect
variable. -
innodb_
xxx
InnoDB
system variables are listed in Section 14.2.4, “InnoDB
Startup Options and System Variables”. -
interactive_timeout
The number of seconds the server waits for activity on an interactive connection before closing it. An interactive client is defined as a client that uses the
CLIENT_INTERACTIVE
option tomysql_real_connect()
. See alsowait_timeout
. -
join_buffer_size
The size of the buffer that is used for joins that do not use indexes and thus perform full table scans. Normally, the best way to get fast joins is to add indexes. Increase the value of
join_buffer_size
to get a faster full join when adding indexes is not possible. One join buffer is allocated for each full join between two tables. For a complex join between several tables for which indexes are not used, multiple join buffers might be necessary. -
Index blocks for
MyISAM
tables are buffered and are shared by all threads.key_buffer_size
is the size of the buffer used for index blocks. The key buffer is also known as the key cache.The maximum allowable setting for
key_buffer_size
is 4GB. 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.Increase the value to get better index handling (for all reads and multiple writes) to as much as you can afford. Using a value that is 25% of total memory on a machine that mainly runs MySQL is quite common. However, if you make the value too large (for example, more than 50% of your total memory) your system might start to page and become extremely slow. MySQL relies on the operating system to perform filesystem caching for data reads, so you must leave some room for the filesystem cache. Consider also the memory requirements of other storage engines.
For even more speed when writing many rows at the same time, use
LOCK TABLES
. See Section 7.2.16, “Speed ofINSERT
Statements”.You can check the performance of the key buffer by issuing a
SHOW STATUS
statement and examining theKey_read_requests
,Key_reads
,Key_write_requests
, andKey_writes
status variables. (See Section 13.5.4, “SHOW
Syntax”.) TheKey_reads/Key_read_requests
ratio should normally be less than 0.01. TheKey_writes/Key_write_requests
ratio is usually near 1 if you are using mostly updates and deletes, but might be much smaller if you tend to do updates that affect many rows at the same time or if you are using theDELAY_KEY_WRITE
table option.The fraction of the key buffer in use can be determined using
key_buffer_size
in conjunction with theKey_blocks_unused
status variable and the buffer block size, which is available from thekey_cache_block_size
system variable:1 - ((Key_blocks_unused × key_cache_block_size) / key_buffer_size)
This value is an approximation because some space in the key buffer may be allocated internally for administrative structures.
It is possible to create multiple
MyISAM
key caches. The size limit of 4GB applies to each cache individually, not as a group. See Section 7.4.6, “TheMyISAM
Key Cache”. -
key_cache_age_threshold
This value controls the demotion of buffers from the hot sub-chain of a key cache to the warm sub-chain. Lower values cause demotion to happen more quickly. The minimum value is 100. The default value is 300. See Section 7.4.6, “The
MyISAM
Key Cache”. -
key_cache_block_size
The size in bytes of blocks in the key cache. The default value is 1024. See Section 7.4.6, “The
MyISAM
Key Cache”. -
key_cache_division_limit
The division point between the hot and warm sub-chains of the key cache buffer chain. The value is the percentage of the buffer chain to use for the warm sub-chain. Allowable values range from 1 to 100. The default value is 100. See Section 7.4.6, “The
MyISAM
Key Cache”. -
language
The language used for error messages.
-
large_file_support
Whether mysqld was compiled with options for large file support.
-
large_pages
Whether large page support is enabled. This variable was added in MySQL 5.0.3.
-
license
The type of license the server has.
-
local_infile
Whether
LOCAL
is supported forLOAD DATA INFILE
statements. See Section 5.7.4, “Security Issues withLOAD DATA LOCAL
”. -
locked_in_memory
Whether mysqld was locked in memory with
--memlock
. -
log
Whether logging of all statements to the general query log is enabled. See Section 5.12.2, “The General Query Log”.
-
log_bin
Whether the binary log is enabled. See Section 5.12.3, “The Binary Log”.
-
log_bin_trust_function_creators
This variable applies when binary logging is enabled. It controls whether stored function creators can be trusted not to create stored functions that will cause unsafe events to be written to the binary log. If set to 0 (the default), users are not allowed to create or alter stored functions unless they have the
SUPER
privilege in addition to theCREATE ROUTINE
orALTER ROUTINE
privilege. A setting of 0 also enforces the restriction that a function must be declared with theDETERMINISTIC
characteristic, or with theREADS SQL DATA
orNO SQL
characteristic. If the variable is set to 1, MySQL does not enforce these restrictions on stored function creation. See Section 17.4, “Binary Logging of Stored Routines and Triggers”.This variable was added in MySQL 5.0.16.
-
log_bin_trust_routine_creators
This is the old name for
log_bin_trust_function_creators
. Before MySQL 5.0.16, it also applies to stored procedures, not just stored functions. As of 5.0.16, this variable is deprecated. It is recognized for backward compatibility but its use results in a warning.This variable was added in MySQL 5.0.6.
-
log_error
The location of the error log.
-
log_queries_not_using_indexes
Whether queries that do not use indexes are logged to the slow query log. See Section 5.12.4, “The Slow Query Log”. This variable was added in MySQL 5.0.23.
-
log_slave_updates
Whether updates received by a slave server from a master server should be logged to the slave's own binary log. Binary logging must be enabled on the slave for this variable to have any effect. See Section 6.8, “Replication Startup Options”.
-
log_slow_queries
Whether slow queries should be logged. “Slow” is determined by the value of the
long_query_time
variable. See Section 5.12.4, “The Slow Query Log”. -
log_warnings
Whether to produce additional warning messages. It is enabled (1) by default. Aborted connections are not logged to the error log unless the value is greater than 1.
-
long_query_time
If a query takes longer than this many seconds, the server increments the
Slow_queries
status variable. If you are using the--log-slow-queries
option, the query is logged to the slow query log file. This value is measured in real time, not CPU time, so a query that is under the threshold on a lightly loaded system might be above the threshold on a heavily loaded one. The minimum value is 1. The default is 10. See Section 5.12.4, “The Slow Query Log”. -
low_priority_updates
If set to
1
, allINSERT
,UPDATE
,DELETE
, andLOCK TABLE WRITE
statements wait until there is no pendingSELECT
orLOCK TABLE READ
on the affected table. This variable previously was namedsql_low_priority_updates
. -
lower_case_file_system
This variable describes the case sensitivity of filenames on the filesystem where the data directory is located.
OFF
means filenames are case sensitive,ON
means they are not case sensitive. -
lower_case_table_names
If set to 1, table names are stored in lowercase on disk and table name 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. See Section 9.2.2, “Identifier Case Sensitivity”.
If you are using
InnoDB
tables, you should set this variable to 1 on all platforms to force names to be converted to lowercase.You should not set this variable to 0 if you are running MySQL on a system that does not have case-sensitive filenames (such as Windows or Mac OS X). If this variable is not set at startup and the filesystem on which the data directory is located does not have case-sensitive filenames, MySQL automatically sets
lower_case_table_names
to 2. -
max_allowed_packet
The maximum size of one packet or any generated/intermediate string.
The packet message buffer is initialized to
net_buffer_length
bytes, but can grow up tomax_allowed_packet
bytes when needed. This value by default is small, to catch large (possibly incorrect) packets.You must increase this value if you are using large
BLOB
columns or long strings. It should be as big as the largestBLOB
you want to use. The protocol limit formax_allowed_packet
is 1GB. -
max_binlog_cache_size
If a multiple-statement transaction requires more than this amount of memory, the server generates a
Multi-statement transaction required more than 'max_binlog_cache_size' bytes of storage
error. -
max_binlog_size
If a write to the binary log causes the current log file size to exceed the value of this variable, the server rotates the binary logs (closes the current file and opens the next one). You cannot set this variable to more than 1GB or to less than 4096 bytes. The default value is 1GB.
A transaction is written in one chunk to the binary log, so it is never split between several binary logs. Therefore, if you have big transactions, you might see binary logs larger than
max_binlog_size
.If
max_relay_log_size
is 0, the value ofmax_binlog_size
applies to relay logs as well. -
max_connect_errors
If there are more than this number of interrupted connections from a host, that host is blocked from further connections. You can unblock blocked hosts with the
FLUSH HOSTS
statement. -
max_connections
The number of simultaneous client connections allowed. Increasing this value increases the number of file descriptors that mysqld requires. See Section 7.4.8, “How MySQL Opens and Closes Tables”, for comments on file descriptor limits. See also Section A.2.6, “
Too many connections
”. -
max_delayed_threads
Do not start more than this number of threads to handle
INSERT DELAYED
statements. If you try to insert data into a new table after allINSERT DELAYED
threads are in use, the row is inserted as if theDELAYED
attribute wasn't specified. If you set this to 0, MySQL never creates a thread to handleDELAYED
rows; in effect, this disablesDELAYED
entirely. -
max_error_count
The maximum number of error, warning, and note messages to be stored for display by the
SHOW ERRORS
andSHOW WARNINGS
statements. -
max_heap_table_size
This variable sets the maximum size to which
MEMORY
tables are allowed to grow. The value of the variable is used to calculateMEMORY
tableMAX_ROWS
values. Setting this variable has no effect on any existingMEMORY
table, unless the table is re-created with a statement such asCREATE TABLE
or altered withALTER TABLE
orTRUNCATE TABLE
. -
max_insert_delayed_threads
This variable is a synonym for
max_delayed_threads
. -
max_join_size
Do not allow
SELECT
statements that probably need to examine more thanmax_join_size
rows (for single-table statements) or row combinations (for multiple-table statements) or that are likely to do more thanmax_join_size
disk seeks. By setting this value, you can catchSELECT
statements where keys are not used properly and that would probably take a long time. Set it if your users tend to perform joins that lack aWHERE
clause, that take a long time, or that return millions of rows.Setting this variable to a value other than
DEFAULT
resets the value ofSQL_BIG_SELECTS
to0
. If you set theSQL_BIG_SELECTS
value again, themax_join_size
variable is ignored.If a query result is in the query cache, no result size check is performed, because the result has previously been computed and it does not burden the server to send it to the client.
This variable previously was named
sql_max_join_size
. -
max_length_for_sort_data
The cutoff on the size of index values that determines which
filesort
algorithm to use. See Section 7.2.12, “ORDER BY
Optimization”. -
max_prepared_stmt_count
This 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. The default value is 16,382. The allowable range of values is from 0 to 1 milliion. 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. This variable was added in MySQL 5.0.21.
-
max_relay_log_size
If a write by a replication slave to its relay log causes the current log file size to exceed the value of this variable, the slave rotates the relay logs (closes the current file and opens the next one). If
max_relay_log_size
is 0, the server usesmax_binlog_size
for both the binary log and the relay log. Ifmax_relay_log_size
is greater than 0, it constrains the size of the relay log, which enables you to have different sizes for the two logs. You must setmax_relay_log_size
to between 4096 bytes and 1GB (inclusive), or to 0. The default value is 0. See Section 6.3, “Replication Implementation Details”. -
max_seeks_for_key
Limit the assumed maximum number of seeks when looking up rows based on a key. The MySQL optimizer assumes that no more than this number of key seeks are required when searching for matching rows in a table by scanning an index, regardless of the actual cardinality of the index (see Section 13.5.4.13, “
SHOW INDEX
Syntax”). By setting this to a low value (say, 100), you can force MySQL to prefer indexes instead of table scans. -
max_sort_length
The number of bytes to use when sorting
BLOB
orTEXT
values. Only the firstmax_sort_length
bytes of each value are used; the rest are ignored. -
max_sp_recursion_depth
The number of times that a stored procedure may call itself. The default value for this option is 0, which completely disallows recursion in stored procedures. The maximum value is 255.
This variable can be set globally and per session.
-
max_tmp_tables
The maximum number of temporary tables a client can keep open at the same time. (This option does not yet do anything.)
-
max_user_connections
The maximum number of simultaneous connections allowed to any given MySQL account. A value of 0 means “no limit.”
Before MySQL 5.0.3, this variable has only global scope. Beginning with MySQL 5.0.3, it also has a read-only session scope. The session variable has the same value as the global variable unless the current account has a non-zero
MAX_USER_CONNECTIONS
resource limit. In that case, the session value reflects the account limit. -
max_write_lock_count
After this many write locks, allow some pending read lock requests to be processed in between.
-
myisam_data_pointer_size
The default pointer size in bytes, to be used by
CREATE TABLE
forMyISAM
tables when noMAX_ROWS
option is specified. This variable cannot be less than 2 or larger than 7. The default value is 6 (4 before MySQL 5.0.6). This variable was added in MySQL 4.1.2. See Section A.2.11, “The table is full
”. -
myisam_max_extra_sort_file_size
(DEPRECATED)If the temporary file used for fast
MyISAM
index creation would be larger than using the key cache by the amount specified here, prefer the key cache method. This is mainly used to force long character keys in large tables to use the slower key cache method to create the index. The value is given in bytes.Note: This variable was removed in MySQL 5.0.6.
-
myisam_max_sort_file_size
The maximum size of the temporary file that MySQL is allowed to use while re-creating a
MyISAM
index (duringREPAIR TABLE
,ALTER TABLE
, orLOAD DATA INFILE
). If the file size would be larger than this value, the index is created using the key cache instead, which is slower. The value is given in bytes. -
myisam_recover_options
The value of the
--myisam-recover
option. See Section 5.2.1, “mysqld Command Options”. -
myisam_repair_threads
If this value is greater than 1,
MyISAM
table indexes are created in parallel (each index in its own thread) during theRepair by sorting
process. The default value is 1.Note: Multi-threaded repair is still beta-quality code.
-
myisam_sort_buffer_size
The size of the buffer that is allocated when sorting
MyISAM
indexes during aREPAIR TABLE
or when creating indexes withCREATE INDEX
orALTER TABLE
. -
myisam_stats_method
How the server treats
NULL
values when collecting statistics about the distribution of index values forMyISAM
tables. This variable has two possible values,nulls_equal
andnulls_unequal
. Fornulls_equal
, allNULL
index values are considered equal and form a single value group that has a size equal to the number ofNULL
values. Fornulls_unequal
,NULL
values are considered unequal, and eachNULL
forms a distinct value group of size 1.The method that is used for generating table statistics influences how the optimizer chooses indexes for query execution, as described in Section 7.4.7, “
MyISAM
Index Statistics Collection”.This variable was added in MySQL 5.0.14. For older versions, the statistics collection method is equivalent to
nulls_equal
. -
multi_read_range
Specifies the maximum number of ranges to send to a storage engine during range selects. The default value is 256. Sending multiple ranges to an engine is a feature that can improve the performance of certain selects dramatically, particularly for
NDBCLUSTER
. This engine needs to send the range requests to all nodes, and sending many of those requests at once reduces the communication costs significantly. This variable was added in MySQL 5.0.3. -
named_pipe
(Windows only.) Indicates whether the server supports connections over named pipes.
-
ndb_autoincrement_prefetch_sz
Determines the probability of gaps in an autoincremented column. Set to
1
to minimize this. Set to a high value for optimization — makes inserts faster, but decreases the likelihood that consecutive autoincrement numbers will be used in a batch of inserts. Default value:32
. Mimimum value:1
. -
ndb_cache_check_time
The number of milliseconds to wait before checking the
NDB
query cache. Setting this to0
(the default and minimum value) means that theNDB
query cache will be checked for validation on every query.The recommended maximum value for this variable is
1000
, which means that the query cache is checked once per second. A larger value means theNDB
query cache is less often checked and invalidated due to updates on a different mysqld. It is generally not desirable to set this to a value greater than2000
. -
ndb_force_send
Forces sending of buffers to
NDB
immediately, without waiting for other threads. Defaults toON
. -
ndb_index_stat_cache_entries
Sets the granularity of the statistics by determining the number of starting and ending keys to store in the statistics memory cache. Zero means no caching takes place; in this case, the data nodes are always queries directly. Default value:
32
. -
ndb_index_stat_enable
Use
NDB
index statistics in query optimization. Defaults toON
. -
ndb_index_stat_update_freq
How often to query data nodes instead of the statistics cache. For example, a value of
20
(the default) means to direct every 20th query to the data nodes. -
ndb_report_thresh_binlog_epoch_slip
This is a threshold on the number of epochs to be behind before reporting binlog status. For example, a value of
3
(the default) means that if the difference between which epoch has been received from the storage nodes and which epoch has been applied to the binlog is 3 or more, a status message will be sent to the cluster log. -
ndb_report_thresh_binlog_mem_usage
This is a threshold on the percentage of free memory remaining before reporting binlog status. For example, a value of
10
(the default) means that if the amount of available memory for receiving binlog data from the data nodes falls below 10%, a status message will be sent to the cluster log. -
ndb_use_exact_count
Forces
NDB
to use an count of records duringSELECT COUNT(*)
query planning to speed up this type of query. The default value isON
. For faster queries overall, disable this feature by setting the value ofndb_use_exact_count
toOFF
. -
ndb_use_transactions
You can disable
NDB
transaction support by setting this variable's values toOFF
(not recommended). The default isON
. -
net_buffer_length
The communication buffer is reset to this size between SQL statements. 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 buffer is automatically enlarged, up to
max_allowed_packet
bytes. -
net_read_timeout
The number of seconds to wait for more data from a connection before aborting the read. This timeout applies only to TCP/IP connections, not to connections made via Unix socket files, named pipes, or shared memory. When the server is reading from the client,
net_read_timeout
is the timeout value controlling when to abort. When the server is writing to the client,net_write_timeout
is the timeout value controlling when to abort. See alsoslave_net_timeout
. -
net_retry_count
If a read 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.
-
net_write_timeout
The number of seconds to wait for a block to be written to a connection before aborting the write. This timeout applies only to TCP/IP connections, not to connections made via Unix socket files, named pipes, or shared memory. See also
net_read_timeout
. -
new
This variable was used in MySQL 4.0 to turn on some 4.1 behaviors, and is retained for backward compatibility. In MySQL 5.0, its value is always
OFF
. -
old_passwords
Whether the server should use pre-4.1-style passwords for MySQL user accounts. See Section A.2.3, “
Client does not support authentication protocol
”. -
one_shot
This is not a variable, but it can be used when setting some variables. It is described in Section 13.5.3, “
SET
Syntax”. -
open_files_limit
The number of files that the operating system allows mysqld to open. This is the real value allowed by the system and might be different from the value you gave using the
--open-files-limit
option to mysqld or mysqld_safe. The value is 0 on systems where MySQL can't change the number of open files. -
optimizer_prune_level
Controls the heuristics applied during query optimization to prune less-promising partial plans from the optimizer search space. A value of 0 disables heuristics so that the optimizer performs an exhaustive search. A value of 1 causes the optimizer to prune plans based on the number of rows retrieved by intermediate plans. This variable was added in MySQL 5.0.1.
-
optimizer_search_depth
The maximum depth of search performed by the query optimizer. Values larger than the number of relations in a query result in better query plans, but take longer to generate an execution plan for a query. Values smaller than the number of relations in a query return an execution plan quicker, but the resulting plan may be far from being optimal. If set to 0, the system automatically picks a reasonable value. If set to the maximum number of tables used in a query plus 2, the optimizer switches to the algorithm used in MySQL 5.0.0 (and previous versions) for performing searches. This variable was added in MySQL 5.0.1.
-
pid_file
The pathname of the process ID (PID) file. This variable can be set with the
--pid-file
option. -
port
The number of the port on which the server listens for TCP/IP connections. This variable can be set with the
--port
option. -
preload_buffer_size
The size of the buffer that is allocated when preloading indexes.
-
prepared_stmt_count
The current number of prepared statements. (The maximum number of statements is given by the
max_prepared_stmt_count
system variable.) This variable was added in MySQL 5.0.21. -
protocol_version
The version of the client/server protocol used by the MySQL server.
-
query_alloc_block_size
The allocation size of memory blocks that are allocated for objects created during statement parsing and execution. If you have problems with memory fragmentation, it might help to increase this a bit.
-
query_cache_limit
Don't cache results that are larger than this number of bytes. The default value is 1MB.
-
query_cache_min_res_unit
The minimum size (in bytes) for blocks allocated by the query cache. The default value is 4096 (4KB). Tuning information for this variable is given in Section 5.14.3, “Query Cache Configuration”.
-
query_cache_size
The amount of memory allocated for caching query results. The default value is 0, which disables the query cache. The allowable values are multiples of 1024; other values are rounded down to the nearest multiple. Note that
query_cache_size
bytes of memory are allocated even ifquery_cache_type
is set to 0. See Section 5.14.3, “Query Cache Configuration”, for more information. -
query_cache_type
Set the query cache type. Setting the
GLOBAL
value sets the type for all clients that connect thereafter. Individual clients can set theSESSION
value to affect their own use of the query cache. Possible values are shown in the following table:Option Description 0
orOFF
Don't cache results in or retrieve results from the query cache. Note that this does not deallocate the query cache buffer. To do that, you should set query_cache_size
to 0.1
orON
Cache all query results except for those that begin with SELECT SQL_NO_CACHE
.2
orDEMAND
Cache results only for queries that begin with SELECT SQL_CACHE
.This variable defaults to
ON
. -
query_cache_wlock_invalidate
Normally, when one client acquires a
WRITE
lock on aMyISAM
table, other clients are not blocked from issuing statements that read from the table if the query results are present in the query cache. Setting this variable to 1 causes acquisition of aWRITE
lock for a table to invalidate any queries in the query cache that refer to the table. This forces other clients that attempt to access the table to wait while the lock is in effect. -
query_prealloc_size
The size of the persistent buffer used for statement parsing and execution. This buffer is not freed between statements. If you are running complex queries, a larger
query_prealloc_size
value might be helpful in improving performance, because it can reduce the need for the server to perform memory allocation during query execution operations. -
range_alloc_block_size
The size of blocks that are allocated when doing range optimization.
-
read_buffer_size
Each thread that does a sequential scan allocates a buffer of this size (in bytes) for each table it scans. If you do many sequential scans, you might want to increase this value, which defaults to 131072.
-
read_only
When the variable is set to
ON
for a replication slave server, it causes the slave to allow no updates except from slave threads or from users that have theSUPER
privilege. This can be useful to ensure that a slave server accepts updates only from its master server and not from clients. As of MySQL 5.0.16, this variable does not apply toTEMPORARY
tables. -
relay_log_purge
Disables or enables automatic purging of relay log files as soon as they are not needed any more. The default value is 1 (
ON
). -
read_rnd_buffer_size
When reading rows in sorted order following a key-sorting operation, the rows are read through this buffer to avoid disk seeks. Setting the variable to a large value can improve
ORDER BY
performance by a lot. However, this is a buffer allocated for each client, so you should not set the global variable to a large value. Instead, change the session variable only from within those clients that need to run large queries. -
rpl_recovery_rank
This variable is unused.
-
secure_auth
If the MySQL server has been started with the
--secure-auth
option, it blocks connections from all accounts that have passwords stored in the old (pre-4.1) format. In that case, the value of this variable isON
, otherwise it isOFF
.You should enable this option if you want to prevent all use of passwords employing the old format (and hence insecure communication over the network).
Server startup fails with an error if this option is enabled and the privilege tables are in pre-4.1 format. See Section A.2.3, “
Client does not support authentication protocol
”. -
server_id
The server ID. This value is set by the
--server-id
option. It is used for replication to enable master and slave servers to identify themselves uniquely. -
shared_memory
(Windows only.) Whether the server allows shared-memory connections.
-
shared_memory_base_name
(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 is
OFF
if mysqld uses external locking,ON
if external locking is disabled. -
skip_networking
This is
ON
if the server allows only local (non-TCP/IP) connections. On Unix, local connections use a Unix socket file. On Windows, local connections use a named pipe or shared memory. On NetWare, only TCP/IP connections are supported, so do not set this variable toON
. This variable can be set toON
with the--skip-networking
option. -
skip_show_database
This prevents people from using the
SHOW DATABASES
statement if they do not have theSHOW DATABASES
privilege. This can improve security if you have concerns about users being able to see databases belonging to other users. Its effect depends on theSHOW DATABASES
privilege: If the variable value isON
, theSHOW DATABASES
statement is allowed only to users who have theSHOW DATABASES
privilege, and the statement displays all database names. If the value isOFF
,SHOW DATABASES
is allowed to all users, but displays the names of only those databases for which the user has theSHOW DATABASES
or other privilege. -
slave_compressed_protocol
Whether to use compression of the slave/master protocol if both the slave and the master support it.
-
slave_load_tmpdir
The name of the directory where the slave creates temporary files for replicating
LOAD DATA INFILE
statements. -
slave_net_timeout
The number of seconds to wait for more data from a master/slave connection before aborting the read. This timeout applies only to TCP/IP connections, not to connections made via Unix socket files, named pipes, or shared memory.
-
slave_skip_errors
The replication errors that the slave should skip (ignore).
-
slave_transaction_retries
If a replication slave SQL thread fails to execute a transaction because of an
InnoDB
deadlock or exceededInnoDB
'sinnodb_lock_wait_timeout
or NDBCluster'sTransactionDeadlockDetectionTimeout
orTransactionInactiveTimeout
, it automatically retriesslave_transaction_retries
times before stopping with an error. The default priot to MySQL 4.0.3 is 0. You must explicitly set the value greater than 0 to enable the “retry” behavior, which is probably a good idea. In MySQL 5.0.3 or newer, the default is 10. -
slow_launch_time
If creating a thread takes longer than this many seconds, the server increments the
Slow_launch_threads
status variable. -
socket
On Unix platforms, this variable is the name of the socket file that is used for local client connections. The default is
/tmp/mysql.sock
. (For some distribution formats, the directory might be different, such as/var/lib/mysql
for RPMs.)On Windows, this variable is the name of the named pipe that is used for local client connections. The default value is
MySQL
(not case sensitive). -
sort_buffer_size
Each thread that needs to do a sort allocates a buffer of this size. Increase this value for faster
ORDER BY
orGROUP BY
operations. See Section A.4.4, “Where MySQL Stores Temporary Files”. -
sql_mode
The current server SQL mode, which can be set dynamically. See Section 5.2.5, “The Server SQL Mode”.
-
sql_slave_skip_counter
The number of events from the master that a slave server should skip. See Section 13.6.2.6, “
SET GLOBAL SQL_SLAVE_SKIP_COUNTER
Syntax”. -
ssl_ca
The path to a file with a list of trusted SSL CAs. This variable was added in MySQL 5.0.23.
-
ssl_capath
The path to a directory that contains trusted SSL CA certificates in PEM format. This variable was added in MySQL 5.0.23.
-
ssl_cert
The name of the SSL certificate file to use for establishing a secure connection. This variable was added in MySQL 5.0.23.
-
ssl_cipher
A list of allowable ciphers to use for SSL encryption. The cipher list has the same format as the
openssl ciphers
command. This variable was added in MySQL 5.0.23. -
ssl_key
The name of the SSL key file to use for establishing a secure connection. This variable was added in MySQL 5.0.23.
-
storage_engine
The default storage engine (table type). To set the storage engine at server startup, use the
--default-storage-engine
option. See Section 5.2.1, “mysqld Command Options”. -
sync_binlog
If the value of this variable is positive, the MySQL server synchronizes its binary log to disk (using
fdatasync()
) after everysync_binlog
writes to the binary log. Note that there is one write to the binary log per statement if autocommit is enabled, and one write per transaction otherwise. The default value is 0, which does no synchronizing to disk. A value of 1 is the safest choice, because in the event of a crash you lose at most one statement or transaction from the binary log. However, it is also the slowest choice (unless the disk has a battery-backed cache, which makes synchronization very fast).If the value of
sync_binlog
is 0 (the default), no extra flushing is done. The server relies on the operating system to flush the file contents occasionaly as for any other file. -
sync_frm
If this variable is set to 1, when any non-temporary table is created its
.frm
file is synchronized to disk (usingfdatasync()
). This is slower but safer in case of a crash. The default is 1. -
system_time_zone
The server system time zone. When the server begins executing, it inherits a time zone setting from the machine defaults, possibly modified by the environment of the account used for running the server or the startup script. The value is used to set
system_time_zone
. Typically the time zone is specified by theTZ
environment variable. It also can be specified using the--timezone
option of the mysqld_safe script.The
system_time_zone
variable differs fromtime_zone
. Although they might have the same value, the latter variable is used to initialize the time zone for each client that connects. See Section 5.11.8, “MySQL Server Time Zone Support”. -
table_cache
The number of open tables for all threads. Increasing this value increases the number of file descriptors that mysqld requires. You can check whether you need to increase the table cache by checking the
Opened_tables
status variable. See Section 5.2.4, “Server Status Variables”. If the value ofOpened_tables
is large and you don't doFLUSH TABLES
often (which just forces all tables to be closed and reopened), then you should increase the value of thetable_cache
variable. For more information about the table cache, see Section 7.4.8, “How MySQL Opens and Closes Tables”. -
table_lock_wait_timeout
Specifies a wait timeout for table-level locks, in seconds. The default timeout is 50 seconds. The timeout is active only if the connection has open cursors. This variable can also be set globally at runtime (you need the
SUPER
privilege to do this). It's available as of MySQL 5.0.10. -
table_type
This variable is a synonym for
storage_engine
. In MySQL 5.0,storage_engine
is the preferred name. -
thread_cache_size
How many threads the server should cache for reuse. When a client disconnects, the client's threads are put in the cache if there are fewer than
thread_cache_size
threads there. Requests for threads are satisfied by reusing threads taken from the cache if possible, and only when the cache is empty is a new thread created. This variable can be increased to improve performance if you have a lot of new connections. (Normally, this doesn't provide a notable performance improvement if you have a good thread implementation.) By examining the difference between theConnections
andThreads_created
status variables, you can see how efficient the thread cache is. For details, see Section 5.2.4, “Server Status Variables”. -
thread_concurrency
On Solaris, mysqld calls
thr_setconcurrency()
with this value. This function enables applications to give the threads system a hint about the desired number of threads that should be run at the same time. -
thread_stack
The stack size for each thread. Many of the limits detected by the
crash-me
test are dependent on this value. The default is large enough for normal operation. See Section 7.1.4, “The MySQL Benchmark Suite”. The default is 192KB. -
time_format
This variable is not implemented.
-
time_zone
The current time zone. This variable is used to initialize the tome 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-zone
option. See Section 5.11.8, “MySQL Server Time Zone Support”. -
tmp_table_size
The maximum size of in-memory temporary tables. (The actual limit is determined as the smaller of
max_heap_table_size
andtmp_table_size
.) If an in-memory temporary table exceeds the limit, MySQL automatically converts it to an on-diskMyISAM
table. Increase the value oftmp_table_size
(andmax_heap_table_size
if necessary) if you do many advancedGROUP BY
queries and you have lots of memory. -
tmpdir
The directory used for temporary files and temporary tables. This variable can be set to a list of several paths that are used in round-robin fashion. Paths should be separated by colon characters (‘
:
’) on Unix and semicolon characters (‘;
’) on Windows, NetWare, and OS/2.The multiple-directory feature can be used to spread the load between several physical disks. If the MySQL server is acting as a replication slave, you should not set
tmpdir
to point to a directory on a memory-based filesystem or to a directory that is cleared when the server host restarts. A replication slave needs some of its temporary files to survive a machine restart so that it can replicate temporary tables orLOAD DATA INFILE
operations. If files in the temporary file directory are lost when the server restarts, replication fails. However, if you are using MySQL 4.0.0 or later, you can set the slave's temporary directory using theslave_load_tmpdir
variable. In that case, the slave won't use the generaltmpdir
value and you can settmpdir
to a non-permanent location. -
transaction_alloc_block_size
The amount in bytes by which to increase a per-transaction memory pool which needs memory. See the description of
transaction_prealloc_size
. -
transaction_prealloc_size
There is a per-transaction memory pool from which various transaction-related allocations take memory. The initial size of the pool in bytes is
transaction_prealloc_size
. For every allocation that cannot be satisfied from the pool because it has insufficient memory available, the pool is increased bytransaction_alloc_block_size
bytes. When the transaction ends, the pool is truncated totransaction_prealloc_size
bytes.By making
transaction_prealloc_size
sufficiently large to contain all statements within a single transaction, you can avoid manymalloc()
calls. -
tx_isolation
The default transaction isolation level. Defaults to
REPEATABLE-READ
.This variable is set by the
SET TRANSACTION ISOLATION LEVEL
statement. See Section 13.4.6, “SET TRANSACTION
Syntax”. If you settx_isolation
directly to an isolation level name that contains a space, the name should be enclosed within quotes, with the space replaced by a dash. For example:SET tx_isolation = 'READ-COMMITTED';
-
updatable_views_with_limit
This variable controls whether updates to a view can be made when the view does not contain all columns of the primary key defined in the underlying table, if the update statement contains a
LIMIT
clause. (Such updates often are generated by GUI tools.) An update is anUPDATE
orDELETE
statement. Primary key here means aPRIMARY KEY
, or aUNIQUE
index in which no column can containNULL
.The variable can have two values:
-
1
orYES
: Issue a warning only (not an error message). This is the default value. -
0
orNO
: Prohibit the update.
This variable was added in MySQL 5.0.2.
-
-
version
The version number for the server.
-
version_bdb
The
BDB
storage engine version. -
version_comment
The configure script has a
--with-comment
option that allows a comment to be specified when building MySQL. This variable contains the value of that comment. -
version_compile_machine
The type of machine or architecture on which MySQL was built.
-
version_compile_os
The type of operating system on which MySQL was built.
-
wait_timeout
The number of seconds the server waits for activity on a non-interactive connection before closing it. This timeout applies only to TCP/IP connections, not to connections made via Unix socket files, named pipes, or shared memory.
On thread startup, the session
wait_timeout
value is initialized from the globalwait_timeout
value or from the globalinteractive_timeout
value, depending on the type of client (as defined by theCLIENT_INTERACTIVE
connect option tomysql_real_connect()
). See alsointeractive_timeout
.
The mysql server maintains many system
variables that indicate how it is configured.
Section 5.2.2, “Server System Variables”, describes the
meaning of these variables. Each system variable has a default
value. System variables can be set at server startup using
options on the command line or in an option file. Most of them
can be changed dynamically while the server is running by
means of the SET
statement, which enables
you to modify operation of the server without having to stop
and restart it. You can refer to system variable values in
expressions.
The server maintains two kinds of system variables. Global variables affect the overall operation of the server. Session variables affect its operation for individual client connections. A given system variable can have both a global and a session value. Global and session system variables are related as follows:
-
When the server starts, it initializes all global variables to their default values. These defaults can be changed by options specified on the command line or in an option file. (See Section 4.3, “Specifying Program Options”.)
-
The server also maintains a set of session variables for each client that connects. The client's session variables are initialized at connect time using the current values of the corresponding global variables. For example, the client's SQL mode is controlled by the session
sql_mode
value, which is initialized when the client connects to the value of the globalsql_mode
value.
System variable values can be set globally at server startup
by using options on the command line or in an option file.
When you use a startup option to set a variable that takes a
numeric value, the value can be given with a suffix of
K
, M
, or
G
(either uppercase or lowercase) to
indicate a multiplier of 1024,
10242 or
10243; that is, units of kilobytes,
megabytes, or gigabygtes, respectively. Thus, the following
command starts the server with a query cache size of 16
megabytes and a maximum packet size of one gigabyte:
mysqld --query_cache_size=16M --max_allowed_packet=1G
Within an option file, those variables are set like this:
[mysqld] query_cache_size=16M max_allowed_packet=1G
The lettercase of suffix letters does not matter;
16M
and 16m
are
equivalent, as are 1G
and
1g
.
If you want to restrict the maximum value to which a system
variable can be set at runtime with the SET
statement, you can specify this maximum by using an option of
the form
--maximum-
var_name
=value
at server startup. For example, to prevent the value of
query_cache_size
from being increased to
more than 32MB at runtime, use the option
--maximum-query_cache_size=32M
.
Many system variables are dynamic and can be changed while the
server runs by using the SET
statement. For
a list, see Section 5.2.3.2, “Dynamic System Variables”. To
change a system variable with SET
, refer to
it as var_name
, optionally preceded
by a modifier:
-
To indicate explicitly that a variable is a global variable, precede its name by
GLOBAL
or@@global.
. TheSUPER
privilege is required to set global variables. -
To indicate explicitly that a variable is a session variable, precede its name by
SESSION
,@@session.
, or@@
. Setting a session variable requires no special privilege, but a client can change only its own session variables, not those of any other client. -
LOCAL
and@@local.
are synonyms forSESSION
and@@session.
. -
If no modifier is present,
SET
changes the session variable.
A SET
statement can contain multiple
variable assignments, separated by commas. If you set several
system variables, the most recent GLOBAL
or
SESSION
modifier in the statement is used
for following variables that have no modifier specified.
Examples:
SET sort_buffer_size=10000; SET @@local.sort_buffer_size=10000; SET GLOBAL sort_buffer_size=1000000, SESSION sort_buffer_size=1000000; SET @@sort_buffer_size=1000000; SET @@global.sort_buffer_size=1000000, @@local.sort_buffer_size=1000000;
When you assign a value to a system variable with
SET
, you cannot use suffix letters in the
value (as can be done with startup options). However, the
value can take the form of an expression:
SET sort_buffer_size = 10 * 1024 * 1024;
The @@
var_name
syntax for system variables is supported for compatibility
with some other database systems.
If you change a session system variable, the value remains in effect until your session ends or until you change the variable to a different value. The change is not visible to other clients.
If you change a global system variable, the value is
remembered and used for new connections until the server
restarts. (To make a global system variable setting permanent,
you should set it in an option file.) The change is visible to
any client that accesses that global variable. However, the
change affects the corresponding session variable only for
clients that connect after the change. The global variable
change does not affect the session variable for any client
that is currently connected (not even that of the client that
issues the SET GLOBAL
statement).
To prevent incorrect usage, MySQL produces an error if you use
SET GLOBAL
with a variable that can only be
used with SET SESSION
or if you do not
specify GLOBAL
(or
@@global.
) when setting a global variable.
To set a SESSION
variable to the
GLOBAL
value or a GLOBAL
value to the compiled-in MySQL default value, use the
DEFAULT
keyword. For example, the following
two statements are identical in setting the session value of
max_join_size
to the global value:
SET max_join_size=DEFAULT; SET @@session.max_join_size=@@global.max_join_size;
Not all system variables can be set to
DEFAULT
. In such cases, use of
DEFAULT
results in an error.
You can refer to the values of specific global or sesson
system variables in expressions by using one of the
@@
-modifiers. For example, you can retrieve
values in a SELECT
statement like this:
SELECT @@global.sql_mode, @@session.sql_mode, @@sql_mode;
When you refer to a system variable in an expression as
@@
var_name
(that
is, when you do not specify @@global.
or
@@session.
), MySQL returns the session
value if it exists and the global value otherwise. (This
differs from SET
@@
var_name
=
value
, which always
refers to the session value.)
Note: Some system variables can be
enabled with the SET
statement by setting
them to ON
or 1
, or
disabled by setting them to OFF
or
0
. However, to set such a variable on the
command line or in an option file, you must set it to
1
or 0
; setting it to
ON
or OFF
will not work.
For example, on the command line,
--delay_key_write=1
works but
--delay_key_write=ON
does not.
To display system variable names and values, use the
SHOW VARIABLES
statement.
mysql> SHOW VARIABLES;
+--------+--------------------------------------------------------------+
| Variable_name | Value |
+--------+--------------------------------------------------------------+
| auto_increment_increment | 1 |
| auto_increment_offset | 1 |
| automatic_sp_privileges | ON |
| back_log | 50 |
| basedir | / |
| bdb_cache_size | 8388600 |
| bdb_home | /var/lib/mysql/ |
| bdb_log_buffer_size | 32768 |
| bdb_logdir | |
| bdb_max_lock | 10000 |
| bdb_shared_data | OFF |
| bdb_tmpdir | /tmp/ |
| binlog_cache_size | 32768 |
| bulk_insert_buffer_size | 8388608 |
| character_set_client | latin1 |
| character_set_connection | latin1 |
| character_set_database | latin1 |
| character_set_results | latin1 |
| character_set_server | latin1 |
| character_set_system | utf8 |
| character_sets_dir | /usr/share/mysql/charsets/ |
| collation_connection | latin1_swedish_ci |
| collation_database | latin1_swedish_ci |
| collation_server | latin1_swedish_ci |
...
| innodb_additional_mem_pool_size | 1048576 |
| innodb_autoextend_increment | 8 |
| innodb_buffer_pool_awe_mem_mb | 0 |
| innodb_buffer_pool_size | 8388608 |
| innodb_checksums | ON |
| innodb_commit_concurrency | 0 |
| innodb_concurrency_tickets | 500 |
| innodb_data_file_path | ibdata1:10M:autoextend |
| innodb_data_home_dir | |
...
| version | 5.0.19-Max |
| version_comment | MySQL Community Edition - Max (GPL) |
| version_compile_machine | i686 |
| version_compile_os | pc-linux-gnu |
| wait_timeout | 28800 |
+--------+--------------------------------------------------------------+
With a LIKE
clause, the statement displays
only those variables that match the pattern. To obtain a
specific variable name, use a LIKE
clause
as shown:
SHOW VARIABLES LIKE 'max_join_size'; SHOW SESSION VARIABLES LIKE 'max_join_size';
To get a list of variables whose name match a pattern, use the
‘%
’ wildcard character in a
LIKE
clause:
SHOW VARIABLES LIKE '%size%'; SHOW GLOBAL VARIABLES LIKE '%size%';
Wildcard characters can be used in any position within the
pattern to be matched. Strictly speaking, because
‘_
’ is a wildcard that matches
any single character, you should escape it as
‘\_
’ to match it literally. In
practice, this is rarely necessary.
For SHOW VARIABLES
, if you specify neither
GLOBAL
nor SESSION
,
MySQL returns SESSION
values.
The reason for requiring the GLOBAL
keyword
when setting GLOBAL
-only variables but not
when retrieving them is to prevent problems in the future. If
we were to remove a SESSION
variable that
has the same name as a GLOBAL
variable, a
client with the SUPER
privilege might
accidentally change the GLOBAL
variable
rather than just the SESSION
variable for
its own connection. If we add a SESSION
variable with the same name as a GLOBAL
variable, a client that intends to change the
GLOBAL
variable might find only its own
SESSION
variable changed.
A structured variable differs from a regular system variable in two respects:
-
Its value is a structure with components that specify server parameters considered to be closely related.
-
There might be several instances of a given type of structured variable. Each one has a different name and refers to a different resource maintained by the server.
MySQL 5.0 supports one structured variable type, which specifies parameters governing the operation of key caches. A key cache structured variable has these components:
-
key_buffer_size
-
key_cache_block_size
-
key_cache_division_limit
-
key_cache_age_threshold
This section describes the syntax for referring to
structured variables. Key cache variables are used for
syntax examples, but specific details about how key caches
operate are found elsewhere, in
Section 7.4.6, “The MyISAM
Key Cache”.
To refer to a component of a structured variable instance,
you can use a compound name in
instance_name.component_name
format. Examples:
hot_cache.key_buffer_size hot_cache.key_cache_block_size cold_cache.key_cache_block_size
For each structured system variable, an instance with the
name of default
is always predefined. If
you refer to a component of a structured variable without
any instance name, the default
instance
is used. Thus, default.key_buffer_size
and key_buffer_size
both refer to the
same system variable.
Structured variable instances and components follow these naming rules:
-
For a given type of structured variable, each instance must have a name that is unique within variables of that type. However, instance names need not be unique across structured variable types. For example, each structured variable has an instance named
default
, sodefault
is not unique across variable types. -
The names of the components of each structured variable type must be unique across all system variable names. If this were not true (that is, if two different types of structured variables could share component member names), it would not be clear which default structured variable to use for references to member names that are not qualified by an instance name.
-
If a structured variable instance name is not legal as an unquoted identifier, refer to it as a quoted identifier using backticks. For example,
hot-cache
is not legal, but`hot-cache`
is. -
global
,session
, andlocal
are not legal instance names. This avoids a conflict with notation such as@@global.
var_name
for referring to non-structured system variables.
Currently, the first two rules have no possibility of being violated because the only structured variable type is the one for key caches. These rules will assume greater significance if some other type of structured variable is created in the future.
With one exception, you can refer to structured variable components using compound names in any context where simple variable names can occur. For example, you can assign a value to a structured variable using a command-line option:
shell> mysqld --hot_cache.key_buffer_size=64K
In an option file, use this syntax:
[mysqld] hot_cache.key_buffer_size=64K
If you start the server with this option, it creates a key
cache named hot_cache
with a size of 64KB
in addition to the default key cache that has a default size
of 8MB.
Suppose that you start the server as follows:
shell>mysqld --key_buffer_size=256K \
--extra_cache.key_buffer_size=128K \
--extra_cache.key_cache_block_size=2048
In this case, the server sets the size of the default key
cache to 256KB. (You could also have written
--default.key_buffer_size=256K
.) In
addition, the server creates a second key cache named
extra_cache
that has a size of 128KB,
with the size of block buffers for caching table index
blocks set to 2048 bytes.
The following example starts the server with three different key caches having sizes in a 3:1:1 ratio:
shell>mysqld --key_buffer_size=6M \
--hot_cache.key_buffer_size=2M \
--cold_cache.key_buffer_size=2M
Structured variable values may be set and retrieved at
runtime as well. For example, to set a key cache named
hot_cache
to a size of 10MB, use either
of these statements:
mysql>SET GLOBAL hot_cache.key_buffer_size = 10*1024*1024;
mysql>SET @@global.hot_cache.key_buffer_size = 10*1024*1024;
To retrieve the cache size, do this:
mysql> SELECT @@global.hot_cache.key_buffer_size;
However, the following statement does not work. The variable
is not interpreted as a compound name, but as a simple
string for a LIKE
pattern-matching
operation:
mysql> SHOW GLOBAL VARIABLES LIKE 'hot_cache.key_buffer_size';
This is the exception to being able to use structured variable names anywhere a simple variable name may occur.
Many server system variables are dynamic and can be set at
runtime using SET GLOBAL
or SET
SESSION
. You can also obtain their values using
SELECT
. See
Section 5.2.3, “Using System Variables”.
The following table shows the full list of all dynamic
system variables. The last column indicates for each
variable whether GLOBAL
or
SESSION
(or both) apply. The table also
lists session options that can be set with the
SET
statement.
Section 13.5.3, “SET
Syntax”, discusses these options.
Variables that have a type of “string” take a
string value. Variables that have a type of
“numeric” take a numeric value. Variables that
have a type of “boolean” can be set to 0, 1,
ON
or OFF
. (If you set
them on the command line or in an option file, use the
numeric values.) Variables that are marked as
“enumeration” normally should be set to one of
the available values for the variable, but can also be set
to the number that corresponds to the desired enumeration
value. For enumerated system variables, the first
enumeration value corresponds to 0. This differs from
ENUM
columns, for which the first
enumeration value corresponds to 1.
Variable Name | Value Type | Type |
autocommit
|
boolean |
SESSION
|
big_tables
|
boolean |
SESSION
|
binlog_cache_size
|
numeric |
GLOBAL
|
bulk_insert_buffer_size
|
numeric | GLOBAL | SESSION |
character_set_client
|
string | GLOBAL | SESSION |
character_set_connection
|
string | GLOBAL | SESSION
|
character_set_filesystem
|
string | GLOBAL | SESSION |
character_set_results
|
string | GLOBAL | SESSION |
character_set_server
|
string | GLOBAL | SESSION |
collation_connection
|
string | GLOBAL | SESSION |
collation_server
|
string | GLOBAL | SESSION |
completion_type
|
numeric | GLOBAL | SESSION |
concurrent_insert
|
numeric |
GLOBAL
|
connect_timeout
|
numeric |
GLOBAL
|
default_week_format
|
numeric | GLOBAL | SESSION |
delay_key_write
|
OFF | ON | ALL |
GLOBAL
|
delayed_insert_limit
|
numeric |
GLOBAL
|
delayed_insert_timeout
|
numeric |
GLOBAL
|
delayed_queue_size
|
numeric |
GLOBAL
|
div_precision_increment
|
numeric | GLOBAL | SESSION |
engine_condition_pushdown
|
boolean | GLOBAL | SESSION |
error_count
|
numeric |
SESSION
|
expire_logs_days
|
numeric |
GLOBAL
|
flush
|
boolean |
GLOBAL
|
flush_time
|
numeric |
GLOBAL
|
foreign_key_checks
|
boolean |
SESSION
|
ft_boolean_syntax
|
numeric |
GLOBAL
|
group_concat_max_len
|
numeric | GLOBAL | SESSION |
identity
|
numeric |
SESSION
|
innodb_autoextend_increment
|
numeric |
GLOBAL
|
innodb_commit_concurrency
|
numeric |
GLOBAL
|
innodb_concurrency_tickets
|
numeric |
GLOBAL
|
innodb_max_dirty_pages_pct
|
numeric |
GLOBAL
|
innodb_max_purge_lag
|
numeric |
GLOBAL
|
innodb_support_xa
|
boolean | GLOBAL | SESSION |
innodb_sync_spin_loops
|
numeric |
GLOBAL
|
innodb_table_locks
|
boolean | GLOBAL | SESSION |
innodb_thread_concurrency
|
numeric |
GLOBAL
|
innodb_thread_sleep_delay
|
numeric |
GLOBAL
|
insert_id
|
boolean |
SESSION
|
interactive_timeout
|
numeric | GLOBAL | SESSION |
join_buffer_size
|
numeric | GLOBAL | SESSION |
key_buffer_size
|
numeric |
GLOBAL
|
last_insert_id |
numeric |
SESSION
|
local_infile
|
boolean |
GLOBAL
|
log_queries_not_using_indexes
|
boolean |
GLOBAL
|
log_warnings
|
numeric |
GLOBAL
|
long_query_time
|
numeric | GLOBAL | SESSION |
low_priority_updates
|
boolean | GLOBAL | SESSION |
max_allowed_packet
|
numeric | GLOBAL | SESSION |
max_binlog_cache_size
|
numeric |
GLOBAL
|
max_binlog_size
|
numeric |
GLOBAL
|
max_connect_errors
|
numeric |
GLOBAL
|
max_connections
|
numeric |
GLOBAL
|
max_delayed_threads
|
numeric |
GLOBAL
|
max_error_count
|
numeric | GLOBAL | SESSION |
max_heap_table_size
|
numeric | GLOBAL | SESSION |
max_insert_delayed_threads
|
numeric |
GLOBAL
|
max_join_size
|
numeric | GLOBAL | SESSION |
max_prepared_stmt_count
|
numeric |
GLOBAL
|
max_relay_log_size
|
numeric |
GLOBAL
|
max_seeks_for_key
|
numeric | GLOBAL | SESSION |
max_sort_length
|
numeric | GLOBAL | SESSION |
max_tmp_tables
|
numeric | GLOBAL | SESSION |
max_user_connections
|
numeric |
GLOBAL
|
max_write_lock_count
|
numeric |
GLOBAL
|
myisam_stats_method
|
enum | GLOBAL | SESSION |
multi_read_range
|
numeric | GLOBAL | SESSION |
myisam_data_pointer_size
|
numeric |
GLOBAL
|
log_bin_trust_function_creators
|
boolean |
GLOBAL
|
myisam_max_sort_file_size
|
numeric | GLOBAL | SESSION |
myisam_repair_threads
|
numeric | GLOBAL | SESSION |
myisam_sort_buffer_size
|
numeric | GLOBAL | SESSION |
net_buffer_length
|
numeric | GLOBAL | SESSION |
net_read_timeout
|
numeric | GLOBAL | SESSION |
net_retry_count
|
numeric | GLOBAL | SESSION |
net_write_timeout
|
numeric | GLOBAL | SESSION |
old_passwords
|
numeric | GLOBAL | SESSION |
optimizer_prune_level
|
numeric | GLOBAL | SESSION |
optimizer_search_depth
|
numeric | GLOBAL | SESSION |
preload_buffer_size
|
numeric | GLOBAL | SESSION |
query_alloc_block_size
|
numeric | GLOBAL | SESSION |
query_cache_limit
|
numeric |
GLOBAL
|
query_cache_size
|
numeric |
GLOBAL
|
query_cache_type
|
enumeration | GLOBAL | SESSION |
query_cache_wlock_invalidate
|
boolean | GLOBAL | SESSION |
query_prealloc_size
|
numeric | GLOBAL | SESSION |
range_alloc_block_size
|
numeric | GLOBAL | SESSION |
read_buffer_size
|
numeric | GLOBAL | SESSION |
read_only
|
numeric |
GLOBAL
|
read_rnd_buffer_size
|
numeric | GLOBAL | SESSION |
rpl_recovery_rank
|
numeric |
GLOBAL
|
safe_show_database
|
boolean |
GLOBAL
|
secure_auth
|
boolean |
GLOBAL
|
server_id
|
numeric |
GLOBAL
|
slave_compressed_protocol
|
boolean |
GLOBAL
|
slave_net_timeout
|
numeric |
GLOBAL
|
slave_transaction_retries
|
numeric |
GLOBAL
|
slow_launch_time
|
numeric |
GLOBAL
|
sort_buffer_size
|
numeric | GLOBAL | SESSION |
sql_auto_is_null
|
boolean |
SESSION
|
sql_big_selects
|
boolean |
SESSION
|
sql_big_tables
|
boolean |
SESSION
|
sql_buffer_result
|
boolean |
SESSION
|
sql_log_bin
|
boolean |
SESSION
|
sql_log_off
|
boolean |
SESSION
|
sql_log_update
|
boolean |
SESSION
|
sql_low_priority_updates
|
boolean | GLOBAL | SESSION |
sql_max_join_size
|
numeric | GLOBAL | SESSION |
sql_mode
|
enumeration | GLOBAL | SESSION |
sql_notes
|
boolean |
SESSION
|
sql_quote_show_create
|
boolean |
SESSION
|
sql_safe_updates
|
boolean |
SESSION
|
sql_select_limit
|
numeric |
SESSION
|
sql_slave_skip_counter
|
numeric |
GLOBAL
|
updatable_views_with_limit
|
enumeration | GLOBAL | SESSION |
sql_warnings
|
boolean |
SESSION
|
sync_binlog
|
numeric |
GLOBAL
|
sync_frm
|
boolean |
GLOBAL
|
storage_engine
|
enumeration | GLOBAL | SESSION |
table_cache
|
numeric |
GLOBAL
|
table_type
|
enumeration | GLOBAL | SESSION |
thread_cache_size
|
numeric |
GLOBAL
|
time_zone
|
string | GLOBAL | SESSION |
timestamp
|
boolean |
SESSION
|
tmp_table_size
|
enumeration | GLOBAL | SESSION |
transaction_alloc_block_size
|
numeric | GLOBAL | SESSION |
transaction_prealloc_size
|
numeric | GLOBAL | SESSION |
tx_isolation
|
enumeration | GLOBAL | SESSION |
unique_checks
|
boolean |
SESSION
|
wait_timeout
|
numeric | GLOBAL | SESSION |
warning_count
|
numeric |
SESSION
|
The server maintains many status variables that provide
information about its operation. You can view these variables
and their values by using the SHOW STATUS
statement:
mysql> SHOW STATUS;
+-----------------------------------+------------+
| Variable_name | Value |
+-----------------------------------+------------+
| Aborted_clients | 0 |
| Aborted_connects | 0 |
| Bytes_received | 155372598 |
| Bytes_sent | 1176560426 |
...
| Connections | 30023 |
| Created_tmp_disk_tables | 0 |
| Created_tmp_files | 3 |
| Created_tmp_tables | 2 |
...
| Threads_created | 217 |
| Threads_running | 88 |
| Uptime | 1389872 |
+-----------------------------------+------------+
Many status variables are reset to 0 by the FLUSH
STATUS
statement.
The status variables have the following meanings. Variables with no version indicated were already present prior to MySQL 5.0. For information regarding their implementation history, see MySQL 3.23, 4.0, 4.1 Reference Manual.
-
Aborted_clients
The number of connections that were aborted because the client died without closing the connection properly. See Section A.2.10, “Communication Errors and Aborted Connections”.
-
Aborted_connects
The number of failed attempts to connect to the MySQL server. See Section A.2.10, “Communication Errors and Aborted Connections”.
-
Binlog_cache_disk_use
The number of transactions that used the temporary binary log cache but that exceeded the value of
binlog_cache_size
and used a temporary file to store statements from the transaction. -
Binlog_cache_use
The number of transactions that used the temporary binary log cache.
-
Bytes_received
The number of bytes received from all clients.
-
Bytes_sent
The number of bytes sent to all clients.
-
Com_
xxx
The
Com_
xxx
statement counter variables indicate the number of times eachxxx
statement has been executed. There is one status variable for each type of statement. For example,Com_delete
andCom_insert
countDELETE
andINSERT
statements, respectively.All of the
Com_stmt_
xxx
variables are increased even if a prepared statement argument is unknown or an error occurred during execution. In other words, their values correspond to the number of requests issued, not to the number of requests successfully completed.The
Com_stmt_
xxx
status variables were added in 5.0.8:-
Com_stmt_prepare
-
Com_stmt_execute
-
Com_stmt_fetch
-
Com_stmt_send_long_data
-
Com_stmt_reset
-
Com_stmt_close
Those variables stand for prepared statement commands. Their names refer to the
COM_
xxx
command set used in the network layer. In other words, their values increase whenever prepared statement API calls such as mysql_stmt_prepare(), mysql_stmt_execute(), and so forth are executed. However,Com_stmt_prepare
,Com_stmt_execute
andCom_stmt_close
also increase forPREPARE
,EXECUTE
, orDEALLOCATE PREPARE
, respectively. Additionally, the values of the older (available since MySQL 4.1.3) statement counter variablesCom_prepare_sql
,Com_execute_sql
, andCom_dealloc_sql
increase for thePREPARE
,EXECUTE
, andDEALLOCATE PREPARE
statements.Com_stmt_fetch
stands for the total number of network round-trips issued when fetching from cursors. -
-
Compression
Whether the client connection uses compression in the client/server protocol. Added in MySQL 5.0.16.
-
Connections
The number of connection attempts (successful or not) to the MySQL server.
-
Created_tmp_disk_tables
The number of temporary tables on disk created automatically by the server while executing statements.
-
Created_tmp_files
How many temporary files mysqld has created.
-
Created_tmp_tables
The number of in-memory temporary tables created automatically by the server while executing statements. If
Created_tmp_disk_tables
is large, you may want to increase thetmp_table_size
value to cause temporary tables to be memory-based instead of disk-based. -
Delayed_errors
The number of rows written with
INSERT DELAYED
for which some error occurred (probablyduplicate key
). -
Delayed_insert_threads
The number of
INSERT DELAYED
handler threads in use. -
Delayed_writes
The number of
INSERT DELAYED
rows written. -
Flush_commands
The number of executed
FLUSH
statements. -
Handler_commit
The number of internal
COMMIT
statements. -
Handler_delete
The number of times that rows have been deleted from tables.
-
Handler_discover
The MySQL server can ask the
NDB Cluster
storage engine if it knows about a table with a given name. This is called discovery.Handler_discover
indicates the number of times that tables have been discovered via this mechanism. -
Handler_prepare
A counter for the prepare phase of two-phase commit operations. Added in MySQL 5.0.3.
-
Handler_read_first
The number of times the first entry was read from an index. If this value is high, it suggests that the server is doing a lot of full index scans; for example,
SELECT col1 FROM foo
, assuming thatcol1
is indexed. -
Handler_read_key
The number of requests to read a row based on a key. If this value is high, it is a good indication that your tables are properly indexed for your queries.
-
Handler_read_next
The number of requests to read the next row in key order. This value is incremented if you are querying an index column with a range constraint or if you are doing an index scan.
-
Handler_read_prev
The number of requests to read the previous row in key order. This read method is mainly used to optimize
ORDER BY ... DESC
. -
Handler_read_rnd
The number of requests to read a row based on a fixed position. This value is high if you are doing a lot of queries that require sorting of the result. You probably have a lot of queries that require MySQL to scan entire tables or you have joins that don't use keys properly.
-
Handler_read_rnd_next
The number of requests to read the next row in the data file. This value is high if you are doing a lot of table scans. Generally this suggests that your tables are not properly indexed or that your queries are not written to take advantage of the indexes you have.
-
Handler_rollback
The number of requests for a storage engine to perform a rollback operation.
-
Handler_savepoint
The number of requests for a storage engine to place a savepoint. Added in MySQL 5.0.3.
-
Handler_savepoint_rollback
The number of requests for a storage engine to roll back to a savepoint. Added in MySQL 5.0.3.
-
Handler_update
The number of requests to update a row in a table.
-
Handler_write
The number of requests to insert a row in a table.
-
Innodb_buffer_pool_pages_data
The number of pages containing data (dirty or clean). Added in MySQL 5.0.2.
-
Innodb_buffer_pool_pages_dirty
The number of pages currently dirty. Added in MySQL 5.0.2.
-
Innodb_buffer_pool_pages_flushed
The number of buffer pool page-flush requests. Added in MySQL 5.0.2.
-
Innodb_buffer_pool_pages_free
The number of free pages. Added in MySQL 5.0.2.
-
Innodb_buffer_pool_pages_latched
The number of latched pages in
InnoDB
buffer pool. These are pages currently being read or written or that cannot be flushed or removed for some other reason. Added in MySQL 5.0.2. -
Innodb_buffer_pool_pages_misc
The number of pages that are busy because they have been allocated for administrative overhead such as row locks or the adaptive hash index. This value can also be calculated as
Innodb_buffer_pool_pages_total
–Innodb_buffer_pool_pages_free
–Innodb_buffer_pool_pages_data
. Added in MySQL 5.0.2. -
Innodb_buffer_pool_pages_total
The total size of buffer pool, in pages. Added in MySQL 5.0.2.
-
Innodb_buffer_pool_read_ahead_rnd
The number of “random” read-aheads initiated by
InnoDB
. This happens when a query scans a large portion of a table but in random order. Added in MySQL 5.0.2. -
Innodb_buffer_pool_read_ahead_seq
The number of sequential read-aheads initiated by
InnoDB
. This happens whenInnoDB
does a sequential full table scan. Added in MySQL 5.0.2. -
Innodb_buffer_pool_read_requests
The number of logical read requests
InnoDB
has done. Added in MySQL 5.0.2. -
Innodb_buffer_pool_reads
The number of logical reads that
InnoDB
could not satisfy from the buffer pool and had to do a single-page read. Added in MySQL 5.0.2. -
Innodb_buffer_pool_wait_free
Normally, writes to the
InnoDB
buffer pool happen in the background. However, if it is necessary to read or create a page and no clean pages are available, it is also necessary to wait for pages to be flushed first. This counter counts instances of these waits. If the buffer pool size has been set properly, this value should be small. Added in MySQL 5.0.2. -
Innodb_buffer_pool_write_requests
The number writes done to the
InnoDB
buffer pool. Added in MySQL 5.0.2. -
Innodb_data_fsyncs
The number of
fsync()
operations so far. Added in MySQL 5.0.2. -
Innodb_data_pending_fsyncs
The current number of pending
fsync()
operations. Added in MySQL 5.0.2. -
Innodb_data_pending_reads
The current number of pending reads. Added in MySQL 5.0.2.
-
Innodb_data_pending_writes
The current number of pending writes. Added in MySQL 5.0.2.
-
Innodb_data_read
The amount of data read so far, in bytes. Added in MySQL 5.0.2.
-
Innodb_data_reads
The total number of data reads. Added in MySQL 5.0.2.
-
Innodb_data_writes
The total number of data writes. Added in MySQL 5.0.2.
-
Innodb_data_written
The amount of data written so far, in bytes. Added in MySQL 5.0.2.
-
Innodb_dblwr_writes
,Innodb_dblwr_pages_written
The number of doublewrite operations that have been performed and the number of pages that have been written for this purpose. Added in MySQL 5.0.2. See Section 14.2.14.1, “
InnoDB
Disk I/O”. -
Innodb_log_waits
The number of times that the log buffer was too small and a wait was required for it to be flushed before continuing. Added in MySQL 5.0.2.
-
Innodb_log_write_requests
The number of log write requests. Added in MySQL 5.0.2.
-
Innodb_log_writes
The number of physical writes to the log file. Added in MySQL 5.0.2.
-
Innodb_os_log_fsyncs
The number of
fsync()
writes done to the log file. Added in MySQL 5.0.2. -
Innodb_os_log_pending_fsyncs
The number of pending log file
fsync()
operations. Added in MySQL 5.0.2. -
Innodb_os_log_pending_writes
The number of pending log file writes. Added in MySQL 5.0.2.
-
Innodb_os_log_written
The number of bytes written to the log file. Added in MySQL 5.0.2.
-
Innodb_page_size
The compiled-in
InnoDB
page size (default 16KB). Many values are counted in pages; the page size allows them to be easily converted to bytes. Added in MySQL 5.0.2. -
Innodb_pages_created
The number of pages created. Added in MySQL 5.0.2.
-
Innodb_pages_read
The number of pages read. Added in MySQL 5.0.2.
-
Innodb_pages_written
The number of pages written. Added in MySQL 5.0.2.
-
Innodb_row_lock_current_waits
The number of row locks currently being waited for. Added in MySQL 5.0.3.
-
Innodb_row_lock_time
The total time spent in acquiring row locks, in milliseconds. Added in MySQL 5.0.3.
-
Innodb_row_lock_time_avg
The average time to acquire a row lock, in milliseconds. Added in MySQL 5.0.3.
-
Innodb_row_lock_time_max
The maximum time to acquire a row lock, in milliseconds. Added in MySQL 5.0.3.
-
Innodb_row_lock_waits
The number of times a row lock had to be waited for. Added in MySQL 5.0.3.
-
Innodb_rows_deleted
The number of rows deleted from
InnoDB
tables. Added in MySQL 5.0.2. -
Innodb_rows_inserted
The number of rows inserted into
InnoDB
tables. Added in MySQL 5.0.2. -
Innodb_rows_read
The number of rows read from
InnoDB
tables. Added in MySQL 5.0.2. -
Innodb_rows_updated
The number of rows updated in
InnoDB
tables. Added in MySQL 5.0.2. -
Key_blocks_not_flushed
The number of key blocks in the key cache that have changed but have not yet been flushed to disk.
-
Key_blocks_unused
The number of unused blocks in the key cache. You can use this value to determine how much of the key cache is in use; see the discussion of
key_buffer_size
in Section 5.2.2, “Server System Variables”. -
Key_blocks_used
The number of used blocks in the key cache. This value is a high-water mark that indicates the maximum number of blocks that have ever been in use at one time.
-
Key_read_requests
The number of requests to read a key block from the cache.
-
Key_reads
The number of physical reads of a key block from disk. If
Key_reads
is large, then yourkey_buffer_size
value is probably too small. The cache miss rate can be calculated asKey_reads
/Key_read_requests
. -
Key_write_requests
The number of requests to write a key block to the cache.
-
Key_writes
The number of physical writes of a key block to disk.
-
Last_query_cost
The total cost of the last compiled query as computed by the query optimizer. This is useful for comparing the cost of different query plans for the same query. The default value of 0 means that no query has been compiled yet. This variable was added in MySQL 5.0.1, with a default value of -1. In MySQL 5.0.7, the default was changed to 0; also in version 5.0.7, the scope of
Last_query_cost
was changed to session rather than global.Prior to MySQL 5.0.16, this variable was not updated for queries served from the query cache.
-
Max_used_connections
The maximum number of connections that have been in use simultaneously since the server started.
-
Ndb_cluster_node_id
If the server is acting as a MySQL Cluster node, then the value of this variable its node ID in the cluster.
If the server is not part of of a MySQL Cluster, then the value of this variable is 0.
-
Ndb_config_from_host
If the server is part of a MySQL Cluster, the value of this variable is the hostname or IP address of the Cluster management server from which it gets its configuration data.
If the server is not part of of a MySQL Cluster, then the value of this variable is an empty string.
Prior to MySQL 5.0.23, this variable was named
Ndb_connected_host
. -
Ndb_config_from_port
If the server is part of a MySQL Cluster, the value of this variable is the number of the port through which it is connected to the CLuster management server from which it gets its configuration data.
If the server is not part of of a MySQL Cluster, then the value of this variable is 0.
Prior to MySQL 5.0.23, this variable was named
Ndb_connected_port
. -
Ndb_number_of_storage_nodes
If the server is part of a MySQL Cluster, the value of this variable is the number of data nodes in the cluster.
If the server is not part of of a MySQL Cluster, then the value of this variable is 0.
-
Not_flushed_delayed_rows
The number of rows waiting to be written in
INSERT DELAY
queues. -
Open_files
The number of files that are open.
-
Open_streams
The number of streams that are open (used mainly for logging).
-
Open_tables
The number of tables that are open.
-
Opened_tables
The number of tables that have been opened. If
Opened_tables
is big, yourtable_cache
value is probably too small. -
Qcache_free_blocks
The number of free memory blocks in the query cache.
-
Qcache_free_memory
The amount of free memory for the query cache.
-
Qcache_hits
The number of query cache hits.
-
Qcache_inserts
The number of queries added to the query cache.
-
Qcache_lowmem_prunes
The number of queries that were deleted from the query cache because of low memory.
-
Qcache_not_cached
The number of non-cached queries (not cacheable, or not cached due to the
query_cache_type
setting). -
Qcache_queries_in_cache
The number of queries registered in the query cache.
-
Qcache_total_blocks
The total number of blocks in the query cache.
-
Questions
The number of statements that clients have sent to the server.
-
Rpl_status
The status of fail-safe replication (not yet implemented).
-
Select_full_join
The number of joins that perform table scans because they do not use indexes. If this value is not 0, you should carefully check the indexes of your tables.
-
Select_full_range_join
The number of joins that used a range search on a reference table.
-
Select_range
The number of joins that used ranges on the first table. This is normally not a critical issue even if the value is quite large.
-
Select_range_check
The number of joins without keys that check for key usage after each row. If this is not 0, you should carefully check the indexes of your tables.
-
Select_scan
The number of joins that did a full scan of the first table.
-
Slave_open_temp_tables
The number of temporary tables that the slave SQL thread currently has open.
-
Slave_running
This is
ON
if this server is a slave that is connected to a master. -
Slave_retried_transactions
The total number of times since startup that the replication slave SQL thread has retried transactions. This variable was added in version 5.0.4.
-
Slow_launch_threads
The number of threads that have taken more than
slow_launch_time
seconds to create. -
Slow_queries
The number of queries that have taken more than
long_query_time
seconds. See Section 5.12.4, “The Slow Query Log”. -
Sort_merge_passes
The number of merge passes that the sort algorithm has had to do. If this value is large, you should consider increasing the value of the
sort_buffer_size
system variable. -
Sort_range
The number of sorts that were done using ranges.
-
Sort_rows
The number of sorted rows.
-
Sort_scan
The number of sorts that were done by scanning the table.
-
Ssl_
xxx
Variables used for SSL connections.
-
Table_locks_immediate
The number of times that a table lock was acquired immediately.
-
Table_locks_waited
The number of times that a table lock could not be acquired immediately and a wait was needed. If this is high and you have performance problems, you should first optimize your queries, and then either split your table or tables or use replication.
-
Threads_cached
The number of threads in the thread cache.
-
Threads_connected
The number of currently open connections.
-
Threads_created
The number of threads created to handle connections. If
Threads_created
is big, you may want to increase thethread_cache_size
value. The cache miss rate can be calculated asThreads_created
/Connections
. -
Threads_running
The number of threads that are not sleeping.
-
Uptime
The number of seconds that the server has been up.
The MySQL server can operate in different SQL modes, and can apply these modes differently for different clients. This capability enables each application to tailor the server's operating mode to its own requirements.
Modes define what SQL syntax MySQL should support and what kind of data validation checks it should perform. This makes it easier to use MySQL in different environments and to use MySQL together with other database servers.
You can set the default SQL mode by starting
mysqld with the
--sql-mode="
modes
"
option. modes
is a list of
different modes separated by comma
(‘,
’) characters. The default
value is empty (no modes set). The
modes
value also can be empty
(--sql-mode=""
) if you want to clear it
explicitly.
You can change the SQL mode at runtime by using a SET
[GLOBAL|SESSION]
sql_mode='
modes
'
statement to set the sql_mode
system value.
Setting the GLOBAL
variable requires the
SUPER
privilege and affects the operation
of all clients that connect from that time on. Setting the
SESSION
variable affects only the current
client. Any client can change its own session
sql_mode
value at any time.
You can retrieve the current global or session
sql_mode
value with the following
statements:
SELECT @@global.sql_mode; SELECT @@session.sql_mode;
The most important sql_mode
values are
probably these:
-
Change syntax and behavior to be more conformant to standard SQL.
-
If a value could not be inserted as given into a transactional table, abort the statement. For a non-transactional table, abort the statement if the value occurs in a single-row statement or the first row of a multiple-row statement. More detail is given later in this section. (Implemented in MySQL 5.0.2)
-
Make MySQL behave like a “traditional” SQL database system. A simple description of this mode is “give an error instead of a warning” when inserting an incorrect value into a column. Note: The
INSERT
/UPDATE
aborts as soon as the error is noticed. This may not be what you want if you are using a non-transactional storage engine, because data changes made prior to the error are not be rolled back, resulting in a “partially done” update. (Added in MySQL 5.0.2)
When this manual refers to “strict mode,” it
means a mode where at least one of
STRICT_TRANS_TABLES
or
STRICT_ALL_TABLES
is enabled.
The following list describes all supported modes:
-
Don't do full checking of dates. Check only that the month is in the range from 1 to 12 and the day is in the range from 1 to 31. This is very convenient for Web applications where you obtain year, month, and day in three different fields and you want to store exactly what the user inserted (without date validation). This mode applies to
DATE
andDATETIME
columns. It does not applyTIMESTAMP
columns, which always require a valid date.This mode is implemented in MySQL 5.0.2. Before 5.0.2, this was the default MySQL date-handling mode. As of 5.0.2, the server requires that month and day values be legal, and not merely in the range 1 to 12 and 1 to 31, respectively. With strict mode disabled, invalid dates such as
'2004-04-31'
are converted to'0000-00-00'
and a warning is generated. With strict mode enabled, invalid dates generate an error. To allow such dates, enableALLOW_INVALID_DATES
. -
Treat ‘
"
’ as an identifier quote character (like the ‘`
’ quote character) and not as a string quote character. You can still use ‘`
’ to quote identifiers with this mode enabled. WithANSI_QUOTES
enabled, you cannot use double quotes to quote literal strings, because it is interpreted as an identifier. -
Produce an error in strict mode (otherwise a warning) when a division by zero (or
MOD(X,0)
) occurs during anINSERT
orUPDATE
. If this mode is not enabled, MySQL instead returnsNULL
for divisions by zero. ForINSERT IGNORE
orUPDATE IGNORE
, MySQL generates a warning for divisions by zero, but the result of the operation isNULL
. (Implemented in MySQL 5.0.2) -
From MySQL 5.0.2 on, the precedence of the
NOT
operator is such that expressions such asNOT a BETWEEN b AND c
are parsed asNOT (a BETWEEN b AND c)
. Before MySQL 5.0.2, the expression is parsed as(NOT a) BETWEEN b AND c
. The old higher-precedence behavior can be obtained by enabling theHIGH_NOT_PRECEDENCE
SQL mode. (Added in MySQL 5.0.2)mysql>
SET sql_mode = '';
mysql>SELECT NOT 1 BETWEEN -5 AND 5;
-> 0 mysql>SET sql_mode = 'broken_not';
mysql>SELECT NOT 1 BETWEEN -5 AND 5;
-> 1 -
Allow spaces between a function name and the ‘
(
’ character. This forces all function names to be treated as reserved words. As a result, if you want to access any database, table, or column name that is a reserved word, you must quote it. For example, because there is aUSER()
function, the name of theuser
table in themysql
database and theUser
column in that table become reserved, so you must quote them:SELECT "User" FROM mysql."user";
The
IGNORE_SPACE
SQL mode applies to built-in functions, not to stored routines. it is always allowable to have spaces after a routine name, regardless of whetherIGNORE_SPACE
is enabled. -
Prevent
GRANT
from automatically creating new users if it would otherwise do so, unless a non-empty password also is specified. (Added in MySQL 5.0.2) -
NO_AUTO_VALUE_ON_ZERO
affects handling ofAUTO_INCREMENT
columns. Normally, you generate the next sequence number for the column by inserting eitherNULL
or0
into it.NO_AUTO_VALUE_ON_ZERO
suppresses this behavior for0
so that onlyNULL
generates the next sequence number.This mode can be useful if
0
has been stored in a table'sAUTO_INCREMENT
column. (Storing0
is not a recommended practice, by the way.) For example, if you dump the table with mysqldump and then reload it, MySQL normally generates new sequence numbers when it encounters the0
values, resulting in a table with contents different from the one that was dumped. EnablingNO_AUTO_VALUE_ON_ZERO
before reloading the dump file solves this problem. mysqldump now automatically includes in its output a statement that enablesNO_AUTO_VALUE_ON_ZERO
, to avoid this problem. -
Disable the use of the backslash character (‘
\
’) as an escape character within strings. With this mode enabled, backslash becomes an ordinary character like any other. (Implemented in MySQL 5.0.1) -
When creating a table, ignore all
INDEX DIRECTORY
andDATA DIRECTORY
directives. This option is useful on slave replication servers. -
NO_ENGINE_SUBSTITUTION
Prevents automatic substitution of the default storage engine when a statement such as
CREATE TABLE
specifies a storage engine that is disabled or not compiled in. (Implemented in MySQL 5.0.8) -
Do not print MySQL-specific column options in the output of
SHOW CREATE TABLE
. This mode is used by mysqldump in portability mode. -
Do not print MySQL-specific index options in the output of
SHOW CREATE TABLE
. This mode is used by mysqldump in portability mode. -
Do not print MySQL-specific table options (such as
ENGINE
) in the output ofSHOW CREATE TABLE
. This mode is used by mysqldump in portability mode. -
In integer subtraction operations, do not mark the result as
UNSIGNED
if one of the operands is unsigned. Note that this makesBIGINT UNSIGNED
not 100% usable in all contexts. See Section 12.8, “Cast Functions and Operators”.mysql>t;
SET sql_mode = '';
mysql>t;SELECT CAST(0 AS UNSIGNED) - 1;
+-------------------------+ | CAST(0 AS UNSIGNED) - 1 | +-------------------------+ | 18446744073709551615 | +-------------------------+ mysql>t;SET sql_mode = 'NO_UNSIGNED_SUBTRACTION';
mysql>t;SELECT CAST(0 AS UNSIGNED) - 1;
+-------------------------+ | CAST(0 AS UNSIGNED) - 1 | +-------------------------+ | -1 | +-------------------------+ -
In strict mode, don't allow
'0000-00-00'
as a valid date. You can still insert zero dates with theIGNORE
option. When not in strict mode, the date is accepted but a warning is generated. (Added in MySQL 5.0.2) -
In strict mode, don't accept dates where the month or day part is 0. If used with the
IGNORE
option, MySQL inserts a'0000-00-00'
date for any such date. When not in strict mode, the date is accepted but a warning is generated. (Added in MySQL 5.0.2) -
Do not allow queries for which the
SELECT
list refers to non-aggregated columns that are not named in theGROUP BY
clause. The following query is invalid with this mode enabled becauseaddress
is not named in theGROUP BY
clause:SELECT name, address, MAX(age) FROM t GROUP BY name;
As of MySQL 5.0.23, this mode also restricts references to non-aggregated columns in the
HAVING
clause that are not named in theGROUP BY
clause. -
Treat
||
as a string concatenation operator (same asCONCAT()
) rather than as a synonym forOR
. -
Treat
REAL
as a synonym forFLOAT
. By default, MySQL treatsREAL
as a synonym forDOUBLE
. -
Enable strict mode for all storage engines. Invalid data values are rejected. Additional detail follows. (Added in MySQL 5.0.2)
-
Enable strict mode for transactional storage engines, and when possible for non-transactional storage engines. Additional details follow. (Implemented in MySQL 5.0.2)
Strict mode controls how MySQL handles input values that are
invalid or missing. A value can be invalid for several
reasons. For example, it might have the wrong data type for
the column, or it might be out of range. A value is missing
when a new row to be inserted does not contain a value for a
column that has no explicit DEFAULT
clause
in its definition.
For transactional tables, an error occurs for invalid or
missing values in a statement when either of the
STRICT_ALL_TABLES
or
STRICT_TRANS_TABLES
modes are enabled. The
statement is aborted and rolled back.
For non-transactional tables, the behavior is the same for either mode, if the bad value occurs in the first row to be inserted or updated. The statement is aborted and the table remains unchanged. If the statement inserts or modifies multiple rows and the bad value occurs in the second or later row, the result depends on which strict option is enabled:
-
For
STRICT_ALL_TABLES
, MySQL returns an error and ignores the rest of the rows. However, in this case, the earlier rows still have been inserted or updated. This means that you might get a partial update, which might not be what you want. To avoid this, it's best to use single-row statements because these can be aborted without changing the table. -
For
STRICT_TRANS_TABLES
, MySQL converts an invalid value to the closest valid value for the column and insert the adjusted value. If a value is missing, MySQL inserts the implicit default value for the column data type. In either case, MySQL generates a warning rather than an error and continues processing the statement. Implicit defaults are described in Section 11.1.4, “Data Type Default Values”.
Strict mode disallows invalid date values such as
'2004-04-31'
. It does not disallow dates
with zero parts such as '2004-04-00'
or
“zero” dates. To disallow these as well, enable
the NO_ZERO_IN_DATE
and
NO_ZERO_DATE
SQL modes in addition to
strict mode.
If you are not using strict mode (that is, neither
STRICT_TRANS_TABLES
nor
STRICT_ALL_TABLES
is enabled), MySQL
inserts adjusted values for invalid or missing values and
produces warnings. In strict mode, you can produce this
behavior by using INSERT IGNORE
or
UPDATE IGNORE
. See
Section 13.5.4.25, “SHOW WARNINGS
Syntax”.
The following special modes are provided as shorthand for
combinations of mode values from the preceding list. All are
available in MySQL 5.0 beginning with version
5.0.0, except for TRADITIONAL
, which was
implemented in MySQL 5.0.2.
The descriptions include all mode values that are available in the most recent version of MySQL. For older versions, a combination mode does not include individual mode values that are not available except in newer versions.
-
Equivalent to
REAL_AS_FLOAT
,PIPES_AS_CONCAT
,ANSI_QUOTES
,IGNORE_SPACE
. Before MySQL 5.0.3,ANSI
also includesONLY_FULL_GROUP_BY
. See Section 1.9.3, “Running MySQL in ANSI Mode”. -
Equivalent to
PIPES_AS_CONCAT
,ANSI_QUOTES
,IGNORE_SPACE
,NO_KEY_OPTIONS
,NO_TABLE_OPTIONS
,NO_FIELD_OPTIONS
. -
Equivalent to
PIPES_AS_CONCAT
,ANSI_QUOTES
,IGNORE_SPACE
,NO_KEY_OPTIONS
,NO_TABLE_OPTIONS
,NO_FIELD_OPTIONS
,NO_AUTO_CREATE_USER
. -
Equivalent to
PIPES_AS_CONCAT
,ANSI_QUOTES
,IGNORE_SPACE
,NO_KEY_OPTIONS
,NO_TABLE_OPTIONS
,NO_FIELD_OPTIONS
. -
Equivalent to
NO_FIELD_OPTIONS
,HIGH_NOT_PRECEDENCE
. -
Equivalent to
NO_FIELD_OPTIONS
,HIGH_NOT_PRECEDENCE
. -
Equivalent to
PIPES_AS_CONCAT
,ANSI_QUOTES
,IGNORE_SPACE
,NO_KEY_OPTIONS
,NO_TABLE_OPTIONS
,NO_FIELD_OPTIONS
,NO_AUTO_CREATE_USER
. -
Equivalent to
PIPES_AS_CONCAT
,ANSI_QUOTES
,IGNORE_SPACE
,NO_KEY_OPTIONS
,NO_TABLE_OPTIONS
,NO_FIELD_OPTIONS
. -
Equivalent to
STRICT_TRANS_TABLES
,STRICT_ALL_TABLES
,NO_ZERO_IN_DATE
,NO_ZERO_DATE
,ERROR_FOR_DIVISION_BY_ZERO
,NO_AUTO_CREATE_USER
.
The server shutdown process takes place as follows:
-
The shutdown process is initiated.
Server shutdown can be initiated several ways. For example, a user with the
SHUTDOWN
privilege can execute a mysqladmin shutdown command. mysqladmin can be used on any platform supported by MySQL. Other operating system-specific shutdown initiation methods are possible as well: The server shuts down on Unix when it receives aSIGTERM
signal. A server running as a service on Windows shuts down when the services manager tells it to. -
The server creates a shutdown thread if necessary.
Depending on how shutdown was initiated, the server might create a thread to handle the shutdown process. If shutdown was requested by a client, a shutdown thread is created. If shutdown is the result of receiving a
SIGTERM
signal, the signal thread might handle shutdown itself, or it might create a separate thread to do so. If the server tries to create a shutdown thread and cannot (for example, if memory is exhausted), it issues a diagnostic message that appears in the error log:Error: Can't create thread to kill server
-
The server stops accepting new connections.
To prevent new activity from being initiated during shutdown, the server stops accepting new client connections. It does this by closing the network connections to which it normally listens for connections: the TCP/IP port, the Unix socket file, the Windows named pipe, and shared memory on Windows.
-
The server terminates current activity.
For each thread that is associated with a client connection, the connection to the client is broken and the thread is marked as killed. Threads die when they notice that they are so marked. Threads for idle connections die quickly. Threads that currently are processing statements check their state periodically and take longer to die. For additional information about thread termination, see Section 13.5.5.3, “
KILL
Syntax”, in particular for the instructions about killedREPAIR TABLE
orOPTIMIZE TABLE
operations onMyISAM
tables.For threads that have an open transaction, the transaction is rolled back. Note that if a thread is updating a non-transactional table, an operation such as a multiple-row
UPDATE
orINSERT
may leave the table partially updated, because the operation can terminate before completion.If the server is a master replication server, threads associated with currently connected slaves are treated like other client threads. That is, each one is marked as killed and exits when it next checks its state.
If the server is a slave replication server, the I/O and SQL threads, if active, are stopped before client threads are marked as killed. The SQL thread is allowed to finish its current statement (to avoid causing replication problems), and then stops. If the SQL thread was in the middle of a transaction at this point, the transaction is rolled back.
-
Storage engines are shut down or closed.
At this stage, the table cache is flushed and all open tables are closed.
Each storage engine performs any actions necessary for tables that it manages. For example,
MyISAM
flushes any pending index writes for a table.InnoDB
flushes its buffer pool to disk (starting from 5.0.5: unlessinnodb_fast_shutdown
is 2), writes the current LSN to the tablespace, and terminates its own internal threads. -
The server exits.
MySQL Server supports a HELP
statement that
returns online information from the MySQL Reference manual
(see Section 13.3.2, “HELP
Syntax”). The proper operation of this
statement requires that the help tables in the
mysql
database be initialized with help
topic information, which is done by processing the contents of
the fill_help_tables.sql
script.
For a MySQL binary distribution on Unix, help table setup occurs when you run mysql_install_db. For an RPM distribution on Linux or binary distribution on Windows, help table setup occurs as part of the MySQL installation process.
For a MySQL source distribution, you can find the
fill_help_tables_sql
file in the
scripts
directory. To load the file
manually, make sure that you have initialized the
mysql
database by running
mysql_install_db, and then process the file
with the mysql client as follows:
shell> mysql -u root mysql < fill_help_tables.sql
If you are working with BitKeeper and a MySQL development
source tree, the tree doesn't contain
fill_help_tables.sql
. You can download
the proper file for your version of MySQL from
http://dev.mysql.com/doc/. After downloading and
uncompressing the file, process it with
mysql as just described.