Table of Contents
InnoDB
TablesMySQL Server (mysqld) is the main program that does most of the work in a MySQL installation. This chapter provides an overview of MySQL Server and covers general server administration:
Server configuration.
The server log files.
Information needed to manage disk space, memory, I/O, and CPU utilization related to MySQL tables.
Management of multiple servers on a single machine.
For additional information on administrative topics, see also:
mysqld is the MySQL server. The following discussion covers these MySQL server configuration topics:
Startup options that the server supports. You can specify these options on the command line, through configuration files, or both.
Server system variables. These variables reflect the current state and values of the startup options, some of which can be modified while the server is running.
Server status variables. These variables contain counters and statistics about runtime operation.
How to set the server SQL mode. This setting modifies certain aspects of SQL syntax and semantics, for example for compatibility with code from other database systems, or to control the error handling for particular situations.
The server shutdown process. There are performance and reliability considerations depending on the type of table (transactional or non-transactional) and whether you use replication.
Not all storage engines are supported by all MySQL server binaries
and configurations. To find out how to determine which storage
engines your MySQL server installation supports, see
Section 13.7.5.17, “SHOW ENGINES
Syntax”.
The following table provides a list of all the command line
options, server and status variables applicable within
mysqld
.
The table lists command-line options (Cmd-line), options valid in configuration files (Option file), server system variables (System Var), and status variables (Status var) in one unified list, with notification of where each option/variable is valid. If a server option set on the command line or in an option file differs from the name of the corresponding server system or status variable, the variable name is noted immediately below the corresponding option. For status variables, the scope of the variable is shown (Scope) as either global, session, or both. Please see the corresponding sections for details on setting and using the options and variables. Where appropriate, a direct link to further information on the item as available.
Table 5.1. Option/Variable Summary
The MySQL server has many operating parameters, which you can change at server startup using command-line options or configuration files (option files). It is also possible to change many parameters at runtime. For general instructions on setting parameters at startup or runtime, see Section 5.1.3, “Server Command Options”, and Section 5.1.4, “Server System Variables”.
Beginning with MySQL 5.6.6, several MySQL Server parameter defaults differ from the defaults in previous releases. The motivation for these changes is to provide better out-of-box performance and to reduce the need for database administrators to change settings manually.
In some cases, a parameter has a different fixed default value.
In other cases, the server autosizes a parameter at startup
using a formula based on other related parameters or server host
configuration, rather than using a fixed value. For example, the
setting for back_log
is its
previous default of 50, adjusted up by an amount proportional to
the value of max_connections
.
The idea behind autosizing is that when the server has
information available to make a decision about a parameter
setting likely to be better than a fixed default, it will.
The following table summarizes changes to defaults. The Version
column indicates when each default changed. For variables that
are autosized, the main variable description provides additional
detail about the sizing algorithm. See
Section 5.1.4, “Server System Variables”, and
Section 14.2.7, “InnoDB
Startup Options and System Variables”. Any of these default
settings can be overridden by specifying an explicit value at
server startup.
Table 5.2. Changes to Server Defaults in MySQL 5.6
In MySQL 5.6.6, the default for
innodb_checksum_algorithm
was
changed from INNODB
to
CRC32
. For compatibility reasons, the default
was returned in 5.6.7 to INNODB
.
As of MySQL 5.6.8, on Unix platforms,
mysql_install_db creates a default option
file named my.cnf
in the base installation
directory. This file is created from a template included in the
distribution package named my-default.cnf
.
You can find the template in or under the base installation
directory. When started using mysqld_safe,
the server uses my.cnf
file by default. If
my.cnf
already exists,
mysql_install_db assumes it to be in use and
writes a new file named my-new.cnf
instead.
With one exception, the settings in the default option file are
commented and have no effect. The exception is that the file
changes the sql_mode
system
variable from its default of
NO_ENGINE_SUBSTITUTION
to also
include STRICT_TRANS_TABLES
.
This setting produces a server configuration that results in
errors rather than warnings for bad data in operations that
modify transactional tables. See
Section 5.1.7, “Server SQL Modes”.
The my-default.cnf
template replaces the
older sample option files formerly supplied with MySQL
distributions (my-small.cnf
,
my-medium.cnf
,
my-large.cnf
, and
my-huge.cnf
). As of MySQL 5.6.8, these
older files are no longer distributed.
On Windows, MySQL Installer interacts with the user and creates
a file named my.ini
in the base
installation directory as the default option file. If you
install on Windows from a Zip archive, you can copy the
my-default.ini
template file in the base
installation directory to my.ini
and use
the latter as the default option file.
On Windows, the .ini
or
.cnf
option file extension might not be
displayed.
On any platform, after completing the installation process, you
can edit the default option file at any time to modify the
parameters used by the server. For example, to use a parameter
setting in the file that is commented with a
#
character at the beginning of the line,
remove the #
, and modify the parameter value
if necessary. To disable a To disable a setting, either add a
#
to the beginning of the line or remove it.
For additional information about option file format and syntax, see Section 4.2.3.3, “Using Option Files”.
Before MySQL 5.6.8, MySQL distributions include several sample
option files that can be used as a basis for tuning the MySQL
server. Look for files named my-small.cnf
,
my-medium.cnf
,
my-large.cnf
, and
my-huge.cnf
, which are sample files for
small, medium, large, and very large systems. On Windows, the
extension is .ini
rather than
.cnf
.
For a binary distribution, look for the sample files in or under
your installation directory. If you have a source distribution,
look in the support-files
directory. To use
a sample file as a base configuration file, rename a copy of it
and place the copy in the appropriate location. Regarding names
and appropriate location, see the general information provided
in Section 4.2.3.3, “Using Option Files”.
When you start the mysqld server, you can specify program options using any of the methods described in Section 4.2.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.2.3.3, “Using Option Files”. That section also describes option file format and syntax.
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
[
groups, where xxxxx
_SERVER]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 6.1.4, “Security-Related mysqld Options and Variables”.
SSL-related options: See Section 6.3.8.4, “SSL Command Options”.
Binary log control options: See Section 5.2.4, “The Binary Log”.
Replication-related options: See Section 16.1.4, “Replication and Binary Logging Options and Variables”.
Options for loading plugins such as pluggable storage engines: See Section 5.1.8.1, “Installing and Uninstalling Plugins”.
Options specific to particular storage engines: See
Section 14.2.7, “InnoDB
Startup Options and System Variables” and
Section 14.3.1, “MyISAM
Startup Options”.
You can also set the values of server system variables by using variable names as options, as described at the end of this section.
Some options control the size of buffers or caches. For a given buffer, the server might need to allocate internal data structures. These structures typically are allocated from the total memory allocated to the buffer, and the amount of space required might be platform dependent. This means that when you assign a value to an option that controls a buffer size, the amount of space actually available might differ from the value assigned. In some cases, the amount might be less than the value assigned. It is also possible that the server will adjust a value upward. For example, if you assign a value of 0 to an option for which the minimal value is 1024, the server will set the value to 1024.
Values for buffer sizes, lengths, and stack sizes are given in bytes unless otherwise specified.
Some options take file name values. Unless otherwise specified,
the default file location is the data directory if the value is a
relative path name. To specify the location explicitly, use an
absolute path name. Suppose that the data directory is
/var/mysql/data
. If a file-valued option is
given as a relative path name, it will be located under
/var/mysql/data
. If the value is an absolute
path name, its location is as given by the path name.
--help
, -?
Command-Line Format | -? | ||
--help | |||
Option-File Format | help |
Display a short help message and exit. Use both the
--verbose
and
--help
options to see the full
message.
Command-Line Format | --allow-suspicious-udfs | ||
Option-File Format | allow-suspicious-udfs | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
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. See
Section 22.3.2.6, “User-Defined Function Security Precautions”.
Command-Line Format | --ansi | ||
-a | |||
Option-File Format | ansi |
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.8.3, “Running MySQL in ANSI Mode”, and
Section 5.1.7, “Server SQL Modes”.
Command-Line Format | --basedir=path | ||
-b | |||
Option-File Format | basedir | ||
Option Sets Variable | Yes, basedir | ||
Variable Name | basedir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The path to the MySQL installation directory. All paths are usually resolved relative to this directory.
Version Removed | 5.6.1 | ||
Command-Line Format | --big-tables | ||
Option-File Format | big-tables | ||
Option Sets Variable | Yes, big_tables | ||
Variable Name | big-tables | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean |
Enable large result sets by saving all temporary sets in files. This option prevents most “table full” errors, but also slows down queries for which in-memory tables would suffice. Since MySQL 3.23.2, the server is able to handle large result sets automatically by using memory for small temporary tables and switching to disk tables where necessary.
Command-Line Format | --bind-address=addr | ||
Option-File Format | bind-address=addr | ||
Variable Name | bind-address | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (<= 5.6.5) | |||
Type | string | ||
Default | 0.0.0.0 | ||
Permitted Values (>= 5.6.6) | |||
Type | string | ||
Default | * |
The MySQL server listens on a single network socket for TCP/IP
connections. This socket is bound to a single address, but it
is possible for an address to map onto multiple network
interfaces. To specify an address, use the
--bind-address=
option at server startup, where
addr
addr
is an IPv4 or IPv6 address or
a host name. If addr
is a host
name, the server resolves the name to an IP address and binds
to that address.
The server treats different types of addresses as follows:
If the address is *
, the server accepts
TCP/IP connections on all server host IPv6 and IPv4
interfaces if the server host supports IPv6, or accepts
TCP/IP connections on all IPv4 addresses otherwise. Use
this address to permit both IPv4 and IPv6 connections on
all server interfaces. This value is permitted (and is the
default) as of MySQL 5.6.6.
If the address is 0.0.0.0
, the server
accepts TCP/IP connections on all server host IPv4
interfaces. This is the default before MySQL 5.6.6.
If the address is ::
, the server
accepts TCP/IP connections on all server host IPv4 and
IPv6 interfaces.
If the address is an IPv4-mapped address, the server
accepts TCP/IP connections for that address, in either
IPv4 or IPv6 format. For example, if the server is bound
to ::ffff:127.0.0.1
, clients can
connect using --host=127.0.0.1
or
--host=::ffff:127.0.0.1
.
If the address is a “regular” IPv4 or IPv6
address (such as 127.0.0.1
or
::1
), the server accepts TCP/IP
connections only for that IPv4 or IPv6 address.
If you intend to bind the server to a specific address, be
sure that the mysql.user
grant table
contains an account with administrative privileges that you
can use to connect to that address. Otherwise, you will not be
able to shut down the server. For example, if you bind the
server to *
, you can connect to it using
all existing accounts. But if you bind the server to
::1
, it accepts connections only on that
address. In that case, first make sure that the
'root'@'::1'
account is present in the
mysql.user
table so you can still connect
to the server to shut it down.
--binlog-format={ROW|STATEMENT|MIXED}
Command-Line Format | --binlog-format=format | ||
Option-File Format | binlog-format=format | ||
Option Sets Variable | Yes, binlog_format | ||
Variable Name | binlog_format | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | STATEMENT | ||
Valid Values |
|
Specify whether to use row-based, statement-based, or mixed replication. Statement-based is the default in MySQL 5.6. See Section 16.1.2, “Replication Formats”.
In MySQL 5.6, setting the binary logging format
without enabling binary logging sets the
binlog_format
global system
variable and logs a warning.
Command-Line Format | --bootstrap | ||
Option-File Format | bootstrap |
This option is used by the mysql_install_db script to create the MySQL privilege tables without having to start a full MySQL server.
This option is unavailable if MySQL was configured with the
DISABLE_GRANT_OPTIONS
compiler
flag. See Section 2.9.4, “MySQL Source-Configuration Options”.
In MySQL 5.6.6 and later, replication and global transaction identifiers are automatically disabled whenever this option is used (Bug #1332602). See Section 16.1.3, “Replication with Global Transaction Identifiers”.
Command-Line Format | --character-sets-dir=path | ||
Option-File Format | character-sets-dir=path | ||
Option Sets Variable | Yes, character_sets_dir | ||
Variable Name | character-sets-dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name |
The directory where character sets are installed. See Section 10.5, “Character Set Configuration”.
--character-set-client-handshake
Command-Line Format | --character-set-client-handshake | ||
Option-File Format | character-set-client-handshake | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
Do not 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
Command-Line Format | --character-set-filesystem=name | ||
Option-File Format | character-set-filesystem | ||
Option Sets Variable | Yes, character_set_filesystem | ||
Variable Name | character_set_filesystem | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The file system character set. This option sets the
character_set_filesystem
system variable.
--character-set-server=
,
charset_name
-C
charset_name
Command-Line Format | --character-set-server | ||
Option-File Format | character-set-server | ||
Option Sets Variable | Yes, character_set_server | ||
Variable Name | character_set_server | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
Use charset_name
as the default
server character set. See
Section 10.5, “Character Set Configuration”. If you use this
option to specify a nondefault character set, you should also
use --collation-server
to
specify the collation.
--chroot=
,
path
-r
path
Command-Line Format | --chroot=name | ||
-r name | |||
Option-File Format | chroot | ||
Permitted Values | |||
Type | file name |
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 limits
LOAD DATA
INFILE
and
SELECT ... INTO
OUTFILE
.
--collation-server=
collation_name
Command-Line Format | --collation-server | ||
Option-File Format | collation-server | ||
Option Sets Variable | Yes, collation_server | ||
Variable Name | collation_server | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
Use collation_name
as the default
server collation. See Section 10.5, “Character Set Configuration”.
Command-Line Format | --console | ||
Option-File Format | console | ||
Platform Specific | windows |
(Windows only.) Write error log messages to
stderr
and stdout
.
mysqld does not close the console window if
this option is used.
Command-Line Format | --core-file | ||
Option-File Format | core-file | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Write a core file if mysqld dies. The name
and location of the core file is system dependent. On Linux, a
core file named
core.
is
written to the current working directory of the process, which
for mysqld is the data directory.
pid
pid
represents the process ID of
the server process. On Mac OS X, a core file named
core.
is
written to the pid
/cores
directory. On
Solaris, use the coreadm command to specify
where to write the core file and how to name it.
For some systems, to get a core file you must also specify the
--core-file-size
option to
mysqld_safe. See
Section 4.3.2, “mysqld_safe — MySQL Server Startup Script”. On some systems, such as
Solaris, you do not get a core file if you are also using the
--user
option. There might be
additional restrictions or limitations. For example, it might
be necessary to execute ulimit -c unlimited
before starting the server. Consult your system documentation.
--datadir=
,
path
-h
path
Command-Line Format | --datadir=path | ||
-h | |||
Option-File Format | datadir | ||
Option Sets Variable | Yes, datadir | ||
Variable Name | datadir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The path to the data directory.
--debug[=
,
debug_options
]-# [
debug_options
]
Command-Line Format | --debug[=debug_options] | ||
Option-File Format | debug | ||
Variable Name | debug | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string | ||
Default | 'd:t:o,/tmp/mysqld.trace' |
If MySQL is configured with
-DWITH_DEBUG=1
, you can use this
option to get a trace file of what mysqld
is doing. A typical debug_options
string is
'd:t:o,
.
The default is file_name
''d:t:i:o,mysqld.trace'
. See
MySQL
Internals: Porting to Other Systems.
Using -DWITH_DEBUG=1
to
configure MySQL with debugging support enables you to use the
--debug="d,parser_debug"
option
when you start the server. This causes the Bison parser that
is used to process SQL statements to dump a parser trace to
the server's standard error output. Typically, this output is
written to the error log.
This option may be given multiple times. Values that begin
with +
or -
are added to
or subtracted from the previous value. For example,
--debug=T
--debug=+P
sets the value to
P:T
.
Command-Line Format | --debug-sync-timeout[=#] | ||
Option-File Format | debug-sync-timeout | ||
Permitted Values | |||
Type | numeric |
Controls whether the Debug Sync facility for testing and
debugging is enabled. Use of Debug Sync requires that MySQL be
configured with the
-DENABLE_DEBUG_SYNC=1
option
(see Section 2.9.4, “MySQL Source-Configuration Options”). If Debug
Sync is not compiled in, this option is not available. The
option value is a timeout in seconds. The default value is 0,
which disables Debug Sync. To enable it, specify a value
greater than 0; this value also becomes the default timeout
for individual synchronization points. If the option is given
without a value, the timeout is set to 300 seconds.
For a description of the Debug Sync facility and how to use synchronization points, see MySQL Internals: Test Synchronization.
--default-authentication-plugin=
plugin_name
Version Introduced | 5.6.6 | ||
Command-Line Format | --default-authentication-plugin=plugin_name | ||
Option-File Format | default-authentication-plugin=plugin_name | ||
Permitted Values | |||
Type | enumeration | ||
Default | mysql_native_password | ||
Valid Values |
|
The default authentication plugin. Acceptable values are
mysql_native_password
(use MySQL native
passwords) and sha256_password
(use SHA-256
passwords). For more information about these plugins, see
Section 6.3.6.1, “The Native Authentication Plugins”, and
Section 6.3.6.2, “The SHA-256 Authentication Plugin”. This option
was added in MySQL 5.6.6.
The value of this option affects these aspects of server operation:
It determines which plugin the server assigns to new accounts for which no plugin is explicitly specified.
It sets the old_passwords
system variable at startup to the value that is consistent
with the password hashing format required by the default
plugin. This in turn affects the password hashing method
used by the PASSWORD()
function.
For an account created with either of the following
statements, the server associates the account with the
default authentication plugin and assigns the account the
given password, hashed according to the value of
old_passwords
.
CREATE USER ... IDENTIFIED BY 'cleartext password
'; GRANT ... IDENTIFIED BY 'cleartext password
';
For an account created with either of the following statements, the statement fails if the password hash is not encrypted using the hash format required by the default authentication plugin. Otherwise, the server associates the account with the default authentication plugin and assigns the account the given password hash.
CREATE USER ... IDENTIFIED BY 'encrypted password
'; GRANT ... IDENTIFIED BY 'encrypted password
';
Command-Line Format | --default-storage-engine=name | ||
Option-File Format | default-storage-engine | ||
Option Sets Variable | Yes, default_storage_engine | ||
Variable Name | default_storage_engine | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | InnoDB |
Set the default storage engine for tables. See
Chapter 14, Storage Engines. As of MySQL 5.6.3, this
option sets the storage engine for permanent tables only. To
set the storage engine for TEMPORARY
tables, set the
default_tmp_storage_engine
system variable.
If you disable the default storage engine at server startup,
you must set the default engine for both permanent and
TEMPORARY
tables to a different engine or
the server will not start.
Command-Line Format | --default-time-zone=name | ||
Option-File Format | default-time-zone | ||
Permitted Values | |||
Type | string |
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 the
system_time_zone
system
variable.
--delay-key-write[={OFF|ON|ALL}]
Command-Line Format | --delay-key-write[=name] | ||
Option-File Format | delay-key-write | ||
Option Sets Variable | Yes, delay_key_write | ||
Variable Name | delay-key-write | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | ON | ||
Valid Values |
|
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 the
DELAY_KEY_WRITE
option.
ALL
delays key writes for all
MyISAM
tables. See
Section 8.11.2, “Tuning Server Parameters”, and
Section 14.3.1, “MyISAM
Startup Options”.
If you set this variable to ALL
, you
should not use MyISAM
tables from within
another program (such as another MySQL server or
myisamchk) when the tables are in use.
Doing so leads to index corruption.
Command-Line Format | --des-key-file=file_name | ||
Option-File Format | des-key-file=file_name |
Read the default DES keys from this file. These keys are used
by the DES_ENCRYPT()
and
DES_DECRYPT()
functions.
Command-Line Format | --enable-named-pipe | ||
Option-File Format | enable-named-pipe | ||
Option Sets Variable | Yes, named_pipe | ||
Platform Specific | windows |
Enable support for named pipes. This option applies only on Windows.
--engine-condition-pushdown={ON|OFF}
Version Removed | 5.6.1 | ||
Command-Line Format | --engine-condition-pushdown | ||
Option-File Format | engine-condition-pushdown | ||
Option Sets Variable | Yes, engine_condition_pushdown | ||
Variable Name | engine_condition_pushdown | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Deprecated | 5.5.3, by optimizer_switch | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
Formerly, this option set the
engine_condition_pushdown
system variable; the option and the variable were both removed
in MySQL 5.6.1. For more information, see
Section 8.13.3, “Engine Condition Pushdown Optimization”.
Command-Line Format | --event-scheduler[=value] | ||
Option-File Format | event-scheduler | ||
Option Sets Variable | Yes, event_scheduler | ||
Variable Name | event_scheduler | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | OFF | ||
Valid Values |
|
Enable or disable, and start or stop, the event scheduler.
For detailed information, see
The
--event-scheduler
Option.
--exit-info[=
,
flags
]-T [
flags
]
Command-Line Format | --exit-info[=flags] | ||
-T [flags] | |||
Option-File Format | exit-info | ||
Permitted Values | |||
Type | numeric |
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!
Command-Line Format | --external-locking | ||
Option-File Format | external-locking | ||
Option Sets Variable | Yes, skip_external_locking | ||
Disabled by | skip-external-locking | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
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.
External locking affects only
MyISAM
table access. For more
information, including conditions under which it can and
cannot be used, see Section 8.10.5, “External Locking”.
Command-Line Format | --flush | ||
Option-File Format | flush | ||
Variable Name | flush | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
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 C.5.4.2, “What to Do If MySQL Keeps Crashing”.
Command-Line Format | --gdb | ||
Option-File Format | gdb | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Install an interrupt handler for SIGINT
(needed to stop mysqld with
^C
to set breakpoints) and disable stack
tracing and core file handling. See
MySQL
Internals: Porting to Other Systems.
Command-Line Format | --general-log | ||
Option-File Format | general-log | ||
Option Sets Variable | Yes, general_log | ||
Variable Name | general_log | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Specify the initial general query log state. With no argument
or an argument of 1, the
--general-log
option enables
the log. If omitted or given with an argument of 0, the option
disables the log.
Version Introduced | 5.6.3 | ||
Command-Line Format | --ignore-db-dir | ||
Option-File Format | ignore-db-dir | ||
Permitted Values | |||
Type | directory name |
This option tells the server to ignore the given directory
name for purposes of the SHOW
DATABASES
statement or
INFORMATION_SCHEMA
tables. For example, if
a MySQL configuration locates the data directory at the root
of a file system on Unix, the system might create a
lost+found
directory there that the
server should ignore. Starting the server with
--ignore-db-dir=lost+found
causes that name not to be listed as a database.
To specify more than one name, use this option multiple times,
once for each name. Specifying the option with an empty value
(that is, as --ignore-db-dir=
)
resets the directory list to the empty list.
Instances of this option given at server startup are used to
set the ignore_db_dirs
system
variable.
This option was added in MySQL 5.6.3.
Command-Line Format | --init-file=file_name | ||
Option-File Format | init-file=file_name | ||
Option Sets Variable | Yes, init_file | ||
Variable Name | init_file | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
Read SQL statements from this file at startup. Each statement must be on a single line and should not include comments.
This option is unavailable if MySQL was configured with the
DISABLE_GRANT_OPTIONS
compiler
flag. See Section 2.9.4, “MySQL Source-Configuration Options”.
--innodb-
xxx
The InnoDB
options are listed in
Section 14.2.7, “InnoDB
Startup Options and System Variables”.
Command-Line Format | --install [service_name] |
(Windows only) Install the server as a Windows service that
starts automatically during Windows startup. The default
service name is MySQL
if no
service_name
value is given. For
more information, see Section 2.3.4.8, “Starting MySQL as a Windows Service”.
--install-manual
[
service_name
]
Command-Line Format | --install-manual [service_name] |
(Windows only) Install the server as a Windows service that
must be started manually. It does not start automatically
during Windows startup. The default service name is
MySQL
if no
service_name
value is given. For
more information, see Section 2.3.4.8, “Starting MySQL as a Windows Service”.
--language=
lang_name
,
-L lang_name
Version Deprecated | 5.6.1 | ||
Command-Line Format | --language=name | ||
-L | |||
Option-File Format | language | ||
Option Sets Variable | Yes, language | ||
Variable Name | language | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Deprecated | 5.6.1 | ||
Permitted Values | |||
Type | directory name | ||
Default | /usr/local/mysql/share/mysql/english/ |
The language to use for error messages.
lang_name
can be given as the
language name or as the full path name to the directory where
the language files are installed. See
Section 10.2, “Setting the Error Message Language”.
In MySQL 5.6,
--lc-messages-dir
and
--lc-messages
should be used
rather than --language
, which
is deprecated as of MySQL 5.6.1 and handled as an alias for
--lc-messages-dir
. The
--language
option will be
removed in a future MySQL release.
Command-Line Format | --large-pages | ||
Option-File Format | large-pages | ||
Option Sets Variable | Yes, large_pages | ||
Variable Name | large_pages | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Platform Specific | linux | ||
Permitted Values | |||
Type (linux) | boolean | ||
Default | FALSE |
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 operating system. Applications that perform a lot of memory accesses may obtain performance improvements by using large pages due to reduced Translation Lookaside Buffer (TLB) misses.
MySQL 5.6 supports the Linux implementation of
large page support (which is called HugeTLB in Linux). See
Section 8.11.4.2, “Enabling Large Page Support”. For Solaris support of
large pages, see the description of the
--super-large-pages
option.
--large-pages
is disabled by
default.
Command-Line Format | --lc-messages=name | ||
Option-File Format | lc-messages | ||
Option Sets Variable | Yes, lc_messages | ||
Variable Name | lc-messages | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The locale to use for error messages. The server converts the
argument to a language name and combines it with the value of
the --lc-messages-dir
to produce the location
for the error message file. See
Section 10.2, “Setting the Error Message Language”.
Command-Line Format | --lc-messages-dir=path | ||
Option-File Format | lc-messages-dir | ||
Option Sets Variable | Yes, lc_messages_dir | ||
Variable Name | lc-messages-dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name |
The directory where error messages are located. The value is
used together with the value of --lc-messages
to produce the location for the error message file. See
Section 10.2, “Setting the Error Message Language”.
--log[=
,
file_name
]-l [
file_name
]
Version Removed | 5.6.1 | ||
Command-Line Format | --log[=name] | ||
-l | |||
Option-File Format | log | ||
Option Sets Variable | Yes, log | ||
Variable Name | log | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Deprecated | 5.1.29, by general-log | ||
Permitted Values | |||
Type | string | ||
Default | OFF |
The --log
option was removed in
MySQL 5.6.1 (along with the
log
system variable).
Instead, use the --general_log
option to enable the general query log and the
--general_log_file=
option to set the general query log file name.
file_name
Command-Line Format | --log-error[=name] | ||
Option-File Format | log-error | ||
Option Sets Variable | Yes, log_error | ||
Variable Name | log_error | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
Log errors and startup messages to this file. See
Section 5.2.2, “The Error Log”. If you omit the file name, MySQL
uses
.
If the file name has no extension, the server adds an
extension of host_name
.err.err
.
Command-Line Format | --log-isam[=name] | ||
Option-File Format | log-isam | ||
Permitted Values | |||
Type | file name |
Log all MyISAM
changes to this file (used
only when debugging MyISAM
).
Command-Line Format | --log-output=name | ||
Option-File Format | log-output | ||
Option Sets Variable | Yes, log_output | ||
Variable Name | log_output | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | set | ||
Default | FILE | ||
Valid Values |
|
This option determines the destination for general query log
and slow query log output. The option value can be given as
one or more of the words TABLE
,
FILE
, or NONE
.
TABLE
select logging to the
general_log
and
slow_log
tables in the
mysql
database as a destination.
FILE
selects logging to log files as a
destination. NONE
disables logging. If
NONE
is present in the option value, it
takes precedence over any other words that are present.
TABLE
and FILE
can both
be given to select to both log output destinations.
This option selects log output destinations, but does not
enable log output. To do that, use the
--general_log
and
--slow_query_log
options. For
FILE
logging, the
--general_log_file
and
-slow_query_log_file
options determine the
log file location. For more information, see
Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”.
--log-queries-not-using-indexes
Command-Line Format | --log-queries-not-using-indexes | ||
Option-File Format | log-queries-not-using-indexes | ||
Option Sets Variable | Yes, log_queries_not_using_indexes | ||
Variable Name | log_queries_not_using_indexes | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
If you are using this option with the slow query log enabled, queries that are expected to retrieve all rows are logged. See Section 5.2.5, “The Slow Query Log”. This option does not necessarily mean that no index is used. For example, a query that uses a full index scan uses an index but would be logged because the index would not limit the number of rows.
Version Introduced | 5.6.3 | ||
Command-Line Format | --log-raw[=value] | ||
Option-File Format | log-raw[=value] | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
As of MySQL 5.6.3, passwords in statements written to the
general query log, slow query log, and binary log are
rewritten by the server not to occur literally in plain text.
Password rewriting can be suppressed for the general query log
by starting the server with the
--log-raw
option. This option
may be useful for diagnostic purposes, to see the exact text
of statements as received by the server, but for security
reasons is not recommended for production use.
Before MySQL 5.6.3, passwords in statements are not rewritten and the general query log should be protected. See Section 6.1.2.3, “Passwords and Logging”.
This option was added in MySQL 5.6.3.
Command-Line Format | --log-short-format | ||
Option-File Format | log-short-format | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Log less information to the binary log and slow query log, if they have been activated.
Command-Line Format | --log-slow-admin-statements | ||
Option-File Format | log-slow-admin-statements | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Log slow administrative statements such as
OPTIMIZE TABLE
,
ANALYZE TABLE
, and
ALTER TABLE
to the slow query
log.
--log-slow-queries[=
file_name
]
Version Removed | 5.6.1 | ||
Command-Line Format | --log-slow-queries[=name] | ||
Option-File Format | log-slow-queries | ||
Option Sets Variable | Yes, log_slow_queries | ||
Variable Name | log_slow_queries | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Deprecated | 5.1.29, by slow-query-log | ||
Permitted Values | |||
Type | boolean |
The --log-slow-queries
option
was removed in MySQL 5.6.1 (along with the
log_slow_queries
system
variable). Instead, use the
--slow_query_log
option to
enable the slow query log and the
--slow_query_log_file=
option to set the slow query log file name.
file_name
Command-Line Format | --log-tc=name | ||
Option-File Format | log-tc | ||
Permitted Values | |||
Type | file name | ||
Default | tc.log |
The name of the memory-mapped transaction coordinator log file
(for XA transactions that affect multiple storage engines when
the binary log is disabled). The default name is
tc.log
. The file is created under the
data directory if not given as a full path name. Currently,
this option is unused.
Command-Line Format | --log-tc-size=# | ||
Option-File Format | log-tc-size | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 24576 | ||
Max Value | 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 24576 | ||
Max Value | 18446744073709547520 |
The size in bytes of the memory-mapped transaction coordinator log. The default size is 24KB.
--log-warnings[=
,
level
]-W [
level
]
Command-Line Format | --log-warnings[=#] | ||
-W [#] | |||
Option-File Format | log-warnings | ||
Option Sets Variable | Yes, log_warnings | ||
Variable Name | log_warnings | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Disabled by | skip-log-warnings | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1 | ||
Range | 0 .. 18446744073709547520 |
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 default
level
value if omitted is 1. To
disable this option, use
--log-warnings=0
. If the value
is greater than 1, aborted connections are written to the
error log, and access-denied errors for new connection
attempts are written. See
Section C.5.2.11, “Communication Errors and Aborted Connections”.
If a slave server was started with
--log-warnings
enabled, the
slave prints messages to the error log to provide information
about its status, such as the binary log and relay log
coordinates where it starts its job, when it is switching to
another relay log, when it reconnects after a disconnect, and
so forth. The server logs messages about statements that are
unsafe for statement-based logging only if
--log-warnings
is enabled.
Command-Line Format | --low-priority-updates | ||
Option-File Format | low-priority-updates | ||
Option Sets Variable | Yes, low_priority_updates | ||
Variable Name | low_priority_updates | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Give table-modifying operations
(INSERT
,
REPLACE
,
DELETE
,
UPDATE
) lower priority than
selects. This can also be done using {INSERT |
REPLACE | DELETE | UPDATE} LOW_PRIORITY ...
to lower
the priority of only one query, or by SET
LOW_PRIORITY_UPDATES=1
to change the priority in one
thread. This affects only storage engines that use only
table-level locking (MyISAM
,
MEMORY
, MERGE
). See
Section 8.10.2, “Table Locking Issues”.
--min-examined-row-limit=
number
Command-Line Format | --min-examined-row-limit=# | ||
Option-File Format | min-examined-row-limit | ||
Variable Name | min_examined_row_limit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 18446744073709547520 |
When this option is set, queries which examine fewer than
number
rows are not written to the
slow query log. The default is 0.
Command-Line Format | --memlock | ||
Option-File Format | memlock | ||
Variable Name | locked_in_memory | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Lock the mysqld process in memory. This option might help if you have a problem where the operating system is causing mysqld to swap to disk.
--memlock
works on systems that
support the mlockall()
system call; this
includes Solaris, most Linux distributions that use a 2.4 or
newer kernel, and perhaps other Unix systems. On Linux
systems, you can tell whether or not
mlockall()
(and thus this option) is
supported by checking to see whether or not it is defined in
the system mman.h
file, like this:
shell> grep mlockall /usr/include/sys/mman.h
If mlockall()
is supported, you should see
in the output of the previous command something like the
following:
extern int mlockall (int __flags) __THROW;
Use of this option may require you to run the server as
root
, which, for reasons of security, is
normally not a good idea. See
Section 6.1.5, “How to Run MySQL as a Normal User”.
On Linux and perhaps other systems, you can avoid the need
to run the server as root
by changing the
limits.conf
file. See the notes
regarding the memlock limit in
Section 8.11.4.2, “Enabling Large Page Support”.
You must not try to use this option on a system that does
not support the mlockall()
system call;
if you do so, mysqld will very likely
crash as soon as you try to start it.
Command-Line Format | --myisam-block-size=# | ||
Option-File Format | myisam-block-size | ||
Permitted Values | |||
Type | numeric | ||
Default | 1024 | ||
Range | 1024 .. 16384 |
The block size to be used for MyISAM
index
pages.
--myisam-recover-options[=
option
[,option
]...]]
Command-Line Format | --myisam-recover-options[=name] | ||
Option-File Format | myisam-recover-options | ||
Option Sets Variable | Yes, myisam_recover_options | ||
Permitted Values | |||
Type | enumeration | ||
Default | OFF | ||
Valid Values |
|
Set the MyISAM
storage engine recovery
mode. The option value is any combination of the values of
OFF
, DEFAULT
,
BACKUP
, FORCE
, or
QUICK
. If you specify multiple values,
separate them by commas. Specifying the option with no
argument is the same as specifying DEFAULT
,
and specifying with an explicit value of ""
disables recovery (same as a value of OFF
).
If recovery is enabled, each time mysqld
opens a MyISAM
table, it checks whether the
table is marked as crashed or was not closed properly. (The
last option works only if you are running with external
locking disabled.) If this is the case,
mysqld runs a check on the table. If the
table was corrupted, mysqld attempts to
repair it.
The following options affect how the repair works.
Option | Description |
---|---|
OFF | No recovery. |
DEFAULT | Recovery without backup, forcing, or quick checking. |
BACKUP | If the data file was changed during recovery, save a backup of the
file as
. |
FORCE | Run recovery even if we would lose more than one row from the
.MYD file. |
QUICK | Do not check the rows in the table if there are not any delete blocks. |
Before the server automatically repairs a table, it writes a
note about the repair to the error log. If you want to be able
to recover from most problems without user intervention, you
should use the options BACKUP,FORCE
. This
forces a repair of a table even if some rows would be deleted,
but it keeps the old data file as a backup so that you can
later examine what happened.
Command-Line Format | --old-alter-table | ||
Option-File Format | old-alter-table | ||
Option Sets Variable | Yes, old_alter_table | ||
Variable Name | old_alter_table | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
When this option is given, the server does not use the
optimized method of processing an ALTER
TABLE
operation. It reverts to using a temporary
table, copying over the data, and then renaming the temporary
table to the original, as used by MySQL 5.0 and earlier. For
more information on the operation of
ALTER TABLE
, see
Section 13.1.6, “ALTER TABLE
Syntax”.
Command-Line Format | --old-style-user-limits | ||
Option-File Format | old-style-user-limits | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Enable old-style user limits. (Before MySQL 5.0.3, account
resource limits were counted separately for each host from
which a user connected rather than per account row in the
user
table.) See
Section 6.3.4, “Setting Account Resource Limits”.
Version Removed | 5.6.1 | ||
Command-Line Format | --one-thread | ||
Option-File Format | one-thread |
This option was removed in MySQL 5.6.1. Use
--thread_handling=no-threads
instead.
Command-Line Format | --open-files-limit=# | ||
Option-File Format | open-files-limit | ||
Option Sets Variable | Yes, open_files_limit | ||
Variable Name | open_files_limit | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (<= 5.6.7) | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 65535 | ||
Permitted Values (>= 5.6.8) | |||
Type | numeric | ||
Default | -1 (autosized) | ||
Range | 0 .. 65535 |
Changes the number of file descriptors available to
mysqld. You should try increasing the value
of this option if mysqld gives you the
error Too many open files
.
mysqld uses the option value to reserve
descriptors with setrlimit()
. If the
requested number of file descriptors cannot be allocated,
mysqld writes a warning to the error log.
mysqld may attempt to allocate more than
the requested number of descriptors (if they are available),
using the values of
max_connections
and
table_open_cache
to estimate
whether more descriptors will be needed.
Command-Line Format | --partition | ||
Option-File Format | partition | ||
Option Sets Variable | Yes, have_partitioning | ||
Variable Name | partition | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Disabled by | skip-partition | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
Enables or disables user-defined partitioning support in the MySQL Server.
--performance_schema_consumer_
consumer_name
=value
Configure a Performance Schema consumer. For details, see Section 20.2.2, “Performance Schema Startup Configuration”.
--performance_schema_instrument=
instrument_name
=value
Configure a Performance Schema instrument. For details, see Section 20.2.2, “Performance Schema Startup Configuration”.
Command-Line Format | --pid-file=file_name | ||
Option-File Format | pid-file=file_name | ||
Option Sets Variable | Yes, pid_file | ||
Variable Name | pid_file | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The path name of the process ID file. The server creates the file in the data directory unless an absolute path name is given to specify a different directory. This file is used by other programs such as mysqld_safe to determine the server's process ID.
Specifies an option that pertains to a server plugin. For
example, many storage engines can be built as plugins, and for
such engines, options for them can be specified with a
--plugin
prefix. Thus, the
--innodb_file_per_table
option
for InnoDB
can be specified as
--plugin-innodb_file_per_table
.
For boolean options that can be enabled or disabled, the
--skip
prefix and other alternative formats
are supported as well (see
Section 4.2.3.2, “Program Option Modifiers”). For example,
--skip-plugin-innodb_file_per_table
disables innodb_file_per_table
.
The rationale for the --plugin
prefix is that
it enables plugin options to be specified unambiguously if
there is a name conflict with a built-in server option. For
example, were a plugin writer to name a plugin
“sql” and implement a “mode” option,
the option name might be
--sql-mode
, which would
conflict with the built-in option of the same name. In such
cases, references to the conflicting name are resolved in
favor of the built-in option. To avoid the ambiguity, users
can specify the plugin option as
--plugin-sql-mode
. Use of the
--plugin
prefix for plugin options is
recommended to avoid any question of ambiguity.
Command-Line Format | --plugin-load=plugin_list | ||
Option-File Format | plugin-load=plugin_list | ||
Permitted Values | |||
Type | string |
This option tells the server to load the named plugins at
startup. The option value is a semicolon-separated list of
pairs. Each name
=plugin_library
name
is the name of the
plugin, and plugin_library
is the
name of the shared library that contains the plugin code. Each
library file must be located in the directory named by the
plugin_dir
system variable.
For example, if plugins named myplug1
and
myplug2
have library files
myplug1.so
and
myplug2.so
, use this option to load them
at startup:
shell> mysqld --plugin-load="myplug1=myplug1.so;myplug2=myplug2.so"
Quotes are used around the argument value here because
semicolon (;
) is interpreted as a special
character by some command interpreters. (Unix shells treat it
as a command terminator, for example.)
If multiple --plugin-load
options are given, only the last one is used. Additional
plugins to load may be specified using
--plugin-load-add
options.
If a plugin library is named without any preceding plugin name, the server loads all plugins in the library.
Each plugin is loaded for a single invocation of
mysqld only. After a restart, the plugin is
not loaded unless --plugin-load
is used again. This is in contrast to
INSTALL PLUGIN
, which adds an
entry to the mysql.plugins
table to cause
the plugin to be loaded for every normal server startup.
Under normal startup, the server determines which plugins to
load by reading the mysql.plugins
system
table. If the server is started with the
--skip-grant-tables
option, it
does not consult the mysql.plugins
table
and does not load plugins listed there.
--plugin-load
enables plugins
to be loaded even when
--skip-grant-tables
is given.
--plugin-load
also enables
plugins to be loaded at startup under configurations when
plugins cannot be loaded at runtime.
For additional information about plugin loading, see Section 5.1.8.1, “Installing and Uninstalling Plugins”.
Version Introduced | 5.6.3 | ||
Command-Line Format | --plugin-load-add=plugin_list | ||
Option-File Format | plugin-load-add=plugin_list | ||
Permitted Values | |||
Type | string |
This option complements the
--plugin-load
option.
--plugin-load-add
adds a plugin
or plugins to the set of plugins to be loaded at startup. The
argument format is the same as for
--plugin-load
.
--plugin-load-add
can be used
to avoid specifying a large set of plugins as a single long
unwieldy --plugin-load
argument. This option was added in MySQL 5.6.3.
--plugin-load-add
can be given
in the absence of
--plugin-load
, but any instance
of --plugin-load-add
that
appears before --plugin-load
.
has no effect because
--plugin-load
resets the set of
plugins to load. In other words, these options:
--plugin-load=x --plugin-load-add=y
are equivalent to this option:
--plugin-load="x;y"
But these options:
--plugin-load-add=y --plugin-load=x
are equivalent to this option:
--plugin-load=x
For additional information about plugin loading, see Section 5.1.8.1, “Installing and Uninstalling Plugins”.
--port=
,
port_num
-P
port_num
Command-Line Format | --port=# | ||
-P | |||
Option-File Format | port | ||
Option Sets Variable | Yes, port | ||
Variable Name | port | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 3306 |
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.
Command-Line Format | --port-open-timeout=# | ||
Option-File Format | port-open-timeout | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 |
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.
Command-Line Format | --remove [service_name] |
(Windows only) Remove a MySQL Windows service. The default
service name is MySQL
if no
service_name
value is given. For
more information, see Section 2.3.4.8, “Starting MySQL as a Windows Service”.
Version Removed | 5.6.6 | ||
Command-Line Format | --safe-mode | ||
Option-File Format | safe-mode | ||
Deprecated | 5.5.26 |
Skip some optimization stages. This option was removed in MySQL 5.6.6.
Command-Line Format | --safe-user-create | ||
Option-File Format | safe-user-create | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
If this option is enabled, a user cannot create new MySQL
users by using the GRANT
statement unless the user has the
INSERT
privilege for the
mysql.user
table or any column in the
table. If you want a user to have the ability to create new
users that have those privileges that the user has the right
to grant, you should grant the user the following privilege:
GRANT INSERT(user) ON mysql.user TO 'user_name
'@'host_name
';
This ensures that the user cannot change any privilege columns
directly, but has to use the
GRANT
statement to give
privileges to other users.
Command-Line Format | --secure-auth | ||
Option-File Format | secure-auth | ||
Option Sets Variable | Yes, secure_auth | ||
Variable Name | secure_auth | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.4) | |||
Type | boolean | ||
Default | OFF | ||
Permitted Values (>= 5.6.5) | |||
Type | boolean | ||
Default | ON |
This option causes the server to block connections by clients
that attempt to use accounts that have passwords stored in the
old (pre-4.1) format. Use it to prevent all use of passwords
employing the old format (and hence insecure communication
over the network). Before MySQL 5.6.5, this option is disabled
by default. As of MySQL 5.6.5, it is enabled by default; to
disable it, use
--skip-secure-auth
.
Server startup fails with an error if this option is enabled
and the privilege tables are in pre-4.1 format. See
Section C.5.2.4, “Client does not support authentication protocol
”.
The mysql client also has a
--secure-auth
option, which
prevents connections to a server if the server requires a
password in old format for the client account.
Command-Line Format | --secure-file-priv=path | ||
Option-File Format | secure-file-priv=path | ||
Option Sets Variable | Yes, secure_file_priv | ||
Variable Name | secure-file-priv | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
This option limits the effect of the
LOAD_FILE()
function and the
LOAD DATA
and
SELECT ... INTO
OUTFILE
statements to work only with files in the
specified directory.
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.
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 8.10.3, “Concurrent Inserts”.
Do not use external locking (system locking). This affects
only MyISAM
table access. For
more information, including conditions under which it can and
cannot be used, see Section 8.10.5, “External Locking”.
External locking has been disabled by default since MySQL 4.0.
Command-Line Format | --skip-event-scheduler | ||
--disable-event-scheduler | |||
Option-File Format | skip-event-scheduler |
Turns the Event Scheduler OFF
. This is not
the same as disabling the Event Scheduler, which requires
setting
--event-scheduler=DISABLED
; see
The
--event-scheduler
Option, for more
information.
This option causes the server to start without using 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 plugins that were
installed with the INSTALL
PLUGIN
statement, user-defined functions (UDFs), and
scheduled events. To cause plugins to be loaded anyway, use
the --plugin-load
option.
--skip-grant-tables
is
unavailable if MySQL was configured with the
DISABLE_GRANT_OPTIONS
compiler
flag. See Section 2.9.4, “MySQL Source-Configuration Options”.
Disable use of the internal host cache for faster name-to-IP resolution. In this case, the server performs a DNS lookup every time a client connects. See Section 8.11.5.2, “DNS Lookup Optimization and the Host Cache”.
Use of --skip-host-cache
is
similar to setting the
host_cache_size
system
variable to 0, but
host_cache_size
is more
flexible because it can also be used to resize, enable, or
disable the host cache at runtime, not just at server startup.
If you start the server with
--skip-host-cache
, the host
cache cannot be re-enabled at runtime.
Disable the InnoDB
storage engine. In this
case, because the default storage engine is
InnoDB
, the server will not start
unless you also use
--default-storage-engine
and
--default-tmp-storage-engine
to
set the default to some other engine for both permanent and
TEMPORARY
tables.
Do not resolve host names when checking client connections.
Use only IP addresses. If you use this option, all
Host
column values in the grant tables must
be IP addresses or localhost
. See
Section 8.11.5.2, “DNS Lookup Optimization and the Host Cache”.
Do not listen for TCP/IP connections at all. All interaction with mysqld must be made using named pipes or shared memory (on Windows) or Unix socket files (on Unix). This option is highly recommended for systems where only local clients are permitted. See Section 8.11.5.2, “DNS Lookup Optimization and the Host Cache”.
Command-Line Format | --skip-partition | ||
--disable-partition | |||
Option-File Format | skip-partition |
Disables user-defined partitioning. Existing partitioned tables cannot be accessed when the server has been started with this option.
Options that begin with --ssl
specify whether to permit clients to connect using SSL and
indicate where to find SSL keys and certificates. See
Section 6.3.8.4, “SSL Command Options”.
Command-Line Format | --standalone | ||
Option-File Format | standalone | ||
Platform Specific | windows |
Available on Windows only; instructs the MySQL server not to run as a service.
Standard use of large pages in MySQL attempts to use the
largest size supported, up to 4MB. Under Solaris, a
“super large pages” feature enables uses of pages
up to 256MB. This feature is available for recent SPARC
platforms. It can be enabled or disabled by using the
--super-large-pages
or
--skip-super-large-pages
option.
--symbolic-links
,
--skip-symbolic-links
Command-Line Format | --symbolic-links | ||
Option-File Format | symbolic-links |
Enable or disable symbolic link support. This option has different effects on Windows and Unix:
On Windows, enabling symbolic links enables you to
establish a symbolic link to a database directory by
creating a
file that contains the path to the real directory. See
Section 8.11.3.1.3, “Using Symbolic Links for Databases on Windows”.
db_name
.sym
On Unix, enabling symbolic links means that you can link a
MyISAM
index file or data file to
another directory with the INDEX
DIRECTORY
or DATA DIRECTORY
options of the CREATE TABLE
statement. If you delete or rename the table, the files
that its symbolic links point to also are deleted or
renamed. See Section 8.11.3.1.2, “Using Symbolic Links for MyISAM
Tables on Unix”.
Command-Line Format | --skip-show-database | ||
Option-File Format | skip-show-database | ||
Option Sets Variable | Yes, skip_show_database | ||
Variable Name | skip_show_database | ||
Variable Scope | Global | ||
Dynamic Variable | No |
With this option, the SHOW
DATABASES
statement is permitted only to users who
have the SHOW DATABASES
privilege, and the statement displays all database names.
Without this option, SHOW
DATABASES
is permitted to all users, but displays
each database name only if the user has the
SHOW DATABASES
privilege or
some privilege for the database. Note that
any global privilege is considered a
privilege for the database.
Command-Line Format | --skip-stack-trace | ||
Option-File Format | skip-stack-trace |
Do not 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 MySQL Internals: Porting to Other Systems.
Version Removed | 5.6.1 | ||
Command-Line Format | --skip-thread-priority | ||
Option-File Format | skip-thread-priority | ||
Deprecated | 5.1.29 |
Disable using thread priorities for faster response time. This option was unused and was removed in MySQL 5.6.1.
Command-Line Format | --slow-query-log | ||
Option-File Format | slow-query-log | ||
Option Sets Variable | Yes, slow_query_log | ||
Variable Name | slow_query_log | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Specify the initial slow query log state. With no argument or
an argument of 1, the
--slow-query-log
option enables
the log. If omitted or given with an argument of 0, the option
disables the log.
Version Introduced | 5.6.5 | ||
Command-Line Format | --slow-start-timeout=# | ||
Option-File Format | slow-start-timeout=# | ||
Permitted Values | |||
Type (windows) | numeric | ||
Default | 15000 |
This option controls the Windows service control manager's service start timeout. The value is the maximum number of milliseconds that the service control manager waits before trying to kill the windows service during startup. The default value is 15000 (15 seconds). If the MySQL service takes too long to start, you may need to increase this value. A value of 0 means there is no timeout.
Command-Line Format | --socket=name | ||
Option-File Format | socket | ||
Option Sets Variable | Yes, socket | ||
Variable Name | socket | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name | ||
Default | /tmp/mysql.sock |
On Unix, this option specifies the Unix socket file to use
when listening for local connections. The default value is
/tmp/mysql.sock
. If this option is given,
the server creates the file in the data directory unless an
absolute path name is given to specify a different directory.
On Windows, the option specifies the pipe name to use when
listening for local connections that use a named pipe. The
default value is MySQL
(not case
sensitive).
--sql-mode=
value
[,value
[,value
...]]
Command-Line Format | --sql-mode=name | ||
Option-File Format | sql-mode | ||
Option Sets Variable | Yes, sql_mode | ||
Variable Name | sql_mode | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Type | set | ||
Default | '' | ||
Valid Values |
| ||
Permitted Values (>= 5.6.6) | |||
Type | set | ||
Default | NO_ENGINE_SUBSTITUTION | ||
Valid Values |
|
Set the SQL mode. Prior to MySQL 5.6.6, the default was
''
(an empty string); beginning with MySQL
5.6.6, the default is
NO_ENGINE_SUBSTITUTION
. See
Section 5.1.7, “Server SQL Modes”.
Command-Line Format | --sysdate-is-now | ||
Option-File Format | sysdate-is-now | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
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 of NOW()
.
This option causes SYSDATE()
to
be an alias for NOW()
. For
information about the implications for binary logging and
replication, see the description for
SYSDATE()
in
Section 12.7, “Date and Time Functions” and for SET
TIMESTAMP
in
Section 5.1.4, “Server System Variables”.
--tc-heuristic-recover={COMMIT|ROLLBACK}
Command-Line Format | --tc-heuristic-recover=name | ||
Option-File Format | tc-heuristic-recover | ||
Permitted Values | |||
Type | enumeration | ||
Valid Values |
|
The type of decision to use in the heuristic recovery process. Currently, this option is unused.
Command-Line Format | --temp-pool | ||
Option-File Format | temp-pool | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
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. This option is ignored except on Linux.
Command-Line Format | --transaction-isolation=name | ||
Option-File Format | transaction-isolation | ||
Option Sets Variable | Yes, tx_isolation | ||
Permitted Values | |||
Type | enumeration | ||
Valid Values |
|
Sets the default transaction isolation level. The
level
value can be
READ-UNCOMMITTED
,
READ-COMMITTED
,
REPEATABLE-READ
, or
SERIALIZABLE
. See
Section 13.3.6, “SET TRANSACTION
Syntax”.
The default transaction isolation level can also be set at
runtime using the SET
TRANSACTION
statement or by setting the
tx_isolation
system variable.
Version Introduced | 5.6.5 | ||
Command-Line Format | --transaction-read-only | ||
Option-File Format | transaction-read-only | ||
Option Sets Variable | Yes, tx_read_only | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Sets the default transaction access mode. By default, read-only mode is disabled, so the mode is read/write.
To set the default transaction access mode at runtime, use the
SET TRANSACTION
statement or
set the tx_read_only
system
variable. See Section 13.3.6, “SET TRANSACTION
Syntax”.
This option was added in MySQL 5.6.5.
--tmpdir=
,
path
-t
path
Command-Line Format | --tmpdir=path | ||
-t | |||
Option-File Format | tmpdir | ||
Option Sets Variable | Yes, tmpdir | ||
Variable Name | tmpdir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
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. If the MySQL server is acting as a replication
slave, you should not set
--tmpdir
to point to a
directory on a memory-based file system or to a directory that
is cleared when the server host restarts. For more information
about the storage location of temporary files, see
Section C.5.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 or
LOAD 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
}
Command-Line Format | --user=name | ||
-u name | |||
Option-File Format | user | ||
Permitted Values | |||
Type | string |
Run the mysqld server as the user having
the name user_name
or the numeric
user ID user_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 as
root
. See
Section 6.1.1, “Security Guidelines”.
To avoid a possible security hole where a user adds a
--user=root
option to a
my.cnf
file (thus causing the server to
run as root
), 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
than root
. The option in
/etc/my.cnf
is found before any other
--user
options, which ensures
that the server runs as a user other than
root
, and that a warning results if any
other --user
option is found.
Use this option with the --help
option for detailed help.
--version
, -V
Display version information and exit.
You can assign a value to a server system variable by using an
option of the form
--
.
For example, var_name
=value
--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 permissible value if only certain values are permitted.
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-
command-line option.
var_name
=value
You can change the values of most system variables for a running
server with the
SET
statement. See Section 13.7.4, “SET
Syntax”.
Section 5.1.4, “Server System Variables”, provides a full description for all variables, and additional information for setting them at server startup and runtime. Section 8.11.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.6 releases. For historical information concerning their implementation, please see http://dev.mysql.com/doc/refman/5.0/en/, and http://dev.mysql.com/doc/refman/4.1/en/.
The following table lists all available system variables:
Table 5.3. System Variable Summary
For additional system variable information, see these sections:
Section 5.1.5, “Using System Variables”, discusses the syntax for setting and displaying system variable values.
Section 5.1.5.2, “Dynamic System Variables”, lists the variables that can be set at runtime.
Information on tuning system variables can be found in Section 8.11.2, “Tuning Server Parameters”.
Section 14.2.7, “InnoDB
Startup Options and System Variables”, lists
InnoDB
system variables.
MySQL Cluster System Variables, lists system variables which are specific to MySQL Cluster.
For information on server system variables specific to replication, see Section 16.1.4, “Replication and Binary Logging Options and Variables”.
Some of the following variable descriptions refer to
“enabling” or “disabling” a variable.
These variables can be enabled with the
SET
statement by setting them to ON
or
1
, or disabled by setting them to
OFF
or 0
. However, before
MySQL 5.6.2, 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. As of MySQL 5.6.2, boolean variables can be set at
startup to the values ON
,
TRUE
, OFF
, and
FALSE
(not case sensitive). See
Section 4.2.3.2, “Program Option Modifiers”.
Some system variables control the size of buffers or caches. For a given buffer, the server might need to allocate internal data structures. These structures typically are allocated from the total memory allocated to the buffer, and the amount of space required might be platform dependent. This means that when you assign a value to a system variable that controls a buffer size, the amount of space actually available might differ from the value assigned. In some cases, the amount might be less than the value assigned. It is also possible that the server will adjust a value upward. For example, if you assign a value of 0 to a variable for which the minimal value is 1024, the server will set the value to 1024.
Values for buffer sizes, lengths, and stack sizes are given in bytes unless otherwise specified.
Some system variables take file name values. Unless otherwise
specified, the default file location is the data directory if the
value is a relative path name. To specify the location explicitly,
use an absolute path name. Suppose that the data directory is
/var/mysql/data
. If a file-valued variable is
given as a relative path name, it will be located under
/var/mysql/data
. If the value is an absolute
path name, its location is as given by the path name.
Command-Line Format | --autocommit[=#] | ||
Option-File Format | autocommit | ||
Option Sets Variable | Yes, autocommit | ||
Variable Name | autocommit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean |
The autocommit mode. If set to 1, all changes to a table take
effect immediately. If set to 0, you must use
COMMIT
to accept a transaction
or ROLLBACK
to cancel it. If autocommit
is 0 and you change it to 1, MySQL performs an automatic
COMMIT
of any open transaction.
Another way to begin a transaction is to use a
START
TRANSACTION
or
BEGIN
statement. See Section 13.3.1, “START TRANSACTION
,
COMMIT
, and
ROLLBACK
Syntax”.
By default, client connections begin with
autocommit
set to 1. To cause
clients to begin with a default of 0, set the global
autocommit
value by starting
the server with the
--autocommit=0
option. To set
the variable using an option file, include these lines:
[mysqld] autocommit=0
Variable Name | automatic_sp_privileges | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
When this variable has a value of 1 (the default), the server
automatically grants the
EXECUTE
and
ALTER ROUTINE
privileges to the
creator of a stored routine, if the user cannot already
execute and alter or drop the routine. (The
ALTER ROUTINE
privilege is
required to drop the routine.) The server also automatically
drops those privileges from the creator when the routine is
dropped. If
automatic_sp_privileges
is 0,
the server does not automatically add or drop these
privileges.
The creator of a routine is the account used to execute the
CREATE
statement for it. This might not be
the same as the account named as the
DEFINER
in the routine definition.
See also Section 18.2.2, “Stored Routines and MySQL Privileges”.
Command-Line Format | --back_log=# | ||
Option-File Format | back_log | ||
Option Sets Variable | Yes, back_log | ||
Variable Name | back_log | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (<= 5.6.5) | |||
Type | numeric | ||
Default | 50 | ||
Range | 1 .. 65535 | ||
Permitted Values (>= 5.6.6) | |||
Type | numeric | ||
Default | -1 (autosized) | ||
Range | 1 .. 65535 |
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.
As of MySQL 5.6.6, the default value is based on the following formula, capped to a limit of 900:
50 + (max_connections / 5)
Before 5.6.6, the default is 50.
Command-Line Format | --basedir=path | ||
-b | |||
Option-File Format | basedir | ||
Option Sets Variable | Yes, basedir | ||
Variable Name | basedir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The MySQL installation base directory. This variable can be
set with the --basedir
option.
Relative path names for other variables usually are resolved
relative to the base directory.
If set to 1, all temporary tables are stored on disk rather
than in memory. This is a little slower, but the error
The table
does not occur for
tbl_name
is
fullSELECT
operations that require
a large temporary table. The default value for a new
connection is 0 (use in-memory temporary tables). Normally,
you should never need to set this variable, because in-memory
tables are automatically converted to disk-based tables as
required.
Command-Line Format | --bind-address=addr | ||
Option-File Format | bind-address=addr | ||
Variable Name | bind-address | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (<= 5.6.5) | |||
Type | string | ||
Default | 0.0.0.0 | ||
Permitted Values (>= 5.6.6) | |||
Type | string | ||
Default | * |
The value of the --bind-address
option. This variable was added in MySQL 5.6.1.
Command-Line Format | --bulk_insert_buffer_size=# | ||
Option-File Format | bulk_insert_buffer_size | ||
Option Sets Variable | Yes, bulk_insert_buffer_size | ||
Variable Name | bulk_insert_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 8388608 | ||
Range | 0 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 8388608 | ||
Range | 0 .. 18446744073709547520 |
MyISAM
uses a special tree-like cache to
make bulk inserts faster for
INSERT ...
SELECT
, INSERT ... VALUES (...), (...),
...
, and
LOAD DATA
INFILE
when adding data to nonempty tables. This
variable limits the size of the cache tree in bytes per
thread. Setting it to 0 disables this optimization. The
default value is 8MB.
Variable Name | character_set_client | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The character set for statements that arrive from the client.
The session value of this variable is set using the character
set requested by the client when the client connects to the
server. (Many clients support a
--default-character-set
option to enable this
character set to be specified explicitly. See also
Section 10.1.4, “Connection Character Sets and Collations”.) The global value of the
variable is used to set the session value in cases when the
client-requested value is unknown or not available, or the
server is configured to ignore client requests:
The client is from a version of MySQL older than MySQL 4.1, and thus does not request a character set.
The client requests a character set not known to the
server. For example, a Japanese-enabled client requests
sjis
when connecting to a server not
configured with sjis
support.
mysqld was started with the
--skip-character-set-client-handshake
option, which causes it to ignore client character set
configuration. This reproduces MySQL 4.0 behavior and is
useful should you wish to upgrade the server without
upgrading all the clients.
ucs2
, utf16
,
utf16le
, and utf32
cannot be used as a client character set, which means that
they also do not work for SET NAMES
or
SET CHARACTER SET
.
Variable Name | character_set_connection | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The character set used for literals that do not have a character set introducer and for number-to-string conversion.
Variable Name | character_set_database | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Footnote | This option is dynamic, but only the server should set this information. You should not set the value of this variable manually. | ||
Permitted Values | |||
Type | string |
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
.
Command-Line Format | --character-set-filesystem=name | ||
Option-File Format | character-set-filesystem | ||
Option Sets Variable | Yes, character_set_filesystem | ||
Variable Name | character_set_filesystem | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The file system character set. This variable is used to
interpret string literals that refer to file names, such as in
the LOAD DATA
INFILE
and
SELECT ... INTO
OUTFILE
statements and the
LOAD_FILE()
function. Such file
names are converted from
character_set_client
to
character_set_filesystem
before the file opening attempt occurs. The default value is
binary
, which means that no conversion
occurs. For systems on which multi-byte file names are
permitted, a different value may be more appropriate. For
example, if the system represents file names using UTF-8, set
character_set_filesystem
to
'utf8'
.
Variable Name | character_set_results | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The character set used for returning query results such as result sets or error messages to the client.
Command-Line Format | --character-set-server | ||
Option-File Format | character-set-server | ||
Option Sets Variable | Yes, character_set_server | ||
Variable Name | character_set_server | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The server's default character set.
Variable Name | character_set_system | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The character set used by the server for storing identifiers.
The value is always utf8
.
Command-Line Format | --character-sets-dir=path | ||
Option-File Format | character-sets-dir=path | ||
Option Sets Variable | Yes, character_sets_dir | ||
Variable Name | character-sets-dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name |
The directory where character sets are installed.
Variable Name | collation_connection | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The collation of the connection character set.
Variable Name | collation_database | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Footnote | This option is dynamic, but only the server should set this information. You should not set the value of this variable manually. | ||
Permitted Values | |||
Type | string |
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
.
Command-Line Format | --collation-server | ||
Option-File Format | collation-server | ||
Option Sets Variable | Yes, collation_server | ||
Variable Name | collation_server | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The server's default collation.
Command-Line Format | --completion_type=# | ||
Option-File Format | completion_type | ||
Option Sets Variable | Yes, completion_type | ||
Variable Name | completion_type | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | NO_CHAIN | ||
Valid Values |
|
The transaction completion type. This variable can take the values shown in the following table. The variable can be assigned using either the name values or corresponding integer values.
Value | Description |
---|---|
NO_CHAIN (or 0) | COMMIT and
ROLLBACK
are unaffected. This is the default value. |
CHAIN (or 1) | COMMIT and
ROLLBACK
are equivalent to COMMIT AND CHAIN
and ROLLBACK AND CHAIN ,
respectively. (A new transaction starts immediately
with the same isolation level as the just-terminated
transaction.) |
RELEASE (or 2) | COMMIT and
ROLLBACK
are equivalent to COMMIT RELEASE
and ROLLBACK RELEASE , respectively.
(The server disconnects after terminating the
transaction.) |
completion_type
affects
transactions that begin with
START
TRANSACTION
or
BEGIN
and
end with COMMIT
or
ROLLBACK
. It
does not apply to implicit commits resulting from execution of
the statements listed in Section 13.3.3, “Statements That Cause an Implicit Commit”. It
also does not apply for
XA
COMMIT
,
XA
ROLLBACK
, or when
autocommit=1
.
Command-Line Format | --concurrent_insert[=#] | ||
Option-File Format | concurrent_insert | ||
Option Sets Variable | Yes, concurrent_insert | ||
Variable Name | concurrent_insert | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | AUTO | ||
Valid Values |
|
If AUTO
(the default), MySQL permits
INSERT
and
SELECT
statements to run
concurrently for MyISAM
tables that have no
free blocks in the middle of the data file. If you start
mysqld with
--skip-new
,
this variable is set to NEVER
.
This variable can take the values shown in the following table. The variable can be assigned using either the name values or corresponding integer values.
Value | Description |
---|---|
NEVER (or 0) | Disables concurrent inserts |
AUTO (or 1) | (Default) Enables concurrent insert for MyISAM tables
that do not have holes |
ALWAYS (or 2) | Enables concurrent inserts for all MyISAM tables,
even those that have holes. For a table with a hole,
new rows are inserted at the end of the table if it is
in use by another thread. Otherwise, MySQL acquires a
normal write lock and inserts the row into the hole. |
See also Section 8.10.3, “Concurrent Inserts”.
Command-Line Format | --connect_timeout=# | ||
Option-File Format | connect_timeout | ||
Option Sets Variable | Yes, connect_timeout | ||
Variable Name | connect_timeout | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 10 |
The number of seconds that the mysqld
server waits for a connect packet before responding with
Bad handshake
. The default value is 10
seconds.
Increasing the
connect_timeout
value might
help if clients frequently encounter errors of the form
Lost connection to MySQL server at
'
.
XXX
', system error:
errno
Version Introduced | 5.6.2 | ||
Variable Name | core_file | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Whether to write a core file if the server crashes. This
variable is set by the
--core-file
option. It was
added in MySQL 5.6.2.
Command-Line Format | --datadir=path | ||
-h | |||
Option-File Format | datadir | ||
Option Sets Variable | Yes, datadir | ||
Variable Name | datadir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The MySQL data directory. This variable can be set with the
--datadir
option.
This variable is unused. It is deprecated as of MySQL 5.6.7 and will be removed in a future MySQL release.
This variable is unused. It is deprecated as of MySQL 5.6.7 and will be removed in a future MySQL release.
Command-Line Format | --debug[=debug_options] | ||
Option-File Format | debug | ||
Variable Name | debug | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string | ||
Default | 'd:t:o,/tmp/mysqld.trace' |
This variable indicates the current debugging settings. It is
available only for servers built with debugging support. The
initial value comes from the value of instances of the
--debug
option given at server
startup. The global and session values may be set at runtime;
the SUPER
privilege is
required, even for the session value.
Assigning a value that begins with +
or
-
cause the value to added to or subtracted
from the current value:
mysql>SET debug = 'T';
mysql>SELECT @@debug;
+---------+ | @@debug | +---------+ | T | +---------+ mysql>SET debug = '+P';
mysql>SELECT @@debug;
+---------+ | @@debug | +---------+ | P:T | +---------+ mysql>SET debug = '-P';
mysql>SELECT @@debug;
+---------+ | @@debug | +---------+ | T | +---------+
Variable Name | debug_sync | ||
Variable Scope | Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
This variable is the user interface to the Debug Sync
facility. Use of Debug Sync requires that MySQL be configured
with the -DENABLE_DEBUG_SYNC=1
option (see Section 2.9.4, “MySQL Source-Configuration Options”).
If Debug Sync is not compiled in, this system variable is not
available.
The global variable value is read only and indicates whether
the facility is enabled. By default, Debug Sync is disabled
and the value of debug_sync
is OFF
. If the server is started with
--debug-sync-timeout=
,
where N
N
is a timeout value greater
than 0, Debug Sync is enabled and the value of
debug_sync
is ON -
current signal
followed by the signal name. Also,
N
becomes the default timeout for
individual synchronization points.
The session value can be read by any user and will have the
same value as the global variable. The session value can be
set by users that have the
SUPER
privilege to control
synchronization points.
For a description of the Debug Sync facility and how to use synchronization points, see MySQL Internals: Test Synchronization.
Command-Line Format | --default-storage-engine=name | ||
Option-File Format | default-storage-engine | ||
Option Sets Variable | Yes, default_storage_engine | ||
Variable Name | default_storage_engine | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | InnoDB |
The default storage engine. As of MySQL 5.6.3, this variable
sets the storage engine for permanent tables only. To set the
storage engine for TEMPORARY
tables, set
the
default_tmp_storage_engine
system variable.
default_storage_engine
should
be used in preference to
storage_engine
, which is
deprecated.
If you disable the default storage engine at server startup,
you must set the default engine for both permanent and
TEMPORARY
tables to a different engine or
the server will not start.
The default storage engine for TEMPORARY
tables (created with
CREATE TEMPORARY
TABLE
). To set the storage engine for permanent
tables, set the
default_storage_engine
system
variable.
If you disable the default storage engine at server startup,
you must set the default engine for both permanent and
TEMPORARY
tables to a different engine or
the server will not start.
default_tmp_storage_engine
was added in MySQL 5.6.3.
Command-Line Format | --default_week_format=# | ||
Option-File Format | default_week_format | ||
Option Sets Variable | Yes, default_week_format | ||
Variable Name | default_week_format | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 7 |
The default mode value to use for the
WEEK()
function. See
Section 12.7, “Date and Time Functions”.
Command-Line Format | --delay-key-write[=name] | ||
Option-File Format | delay-key-write | ||
Option Sets Variable | Yes, delay_key_write | ||
Variable Name | delay-key-write | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | ON | ||
Valid Values |
|
This option applies only to MyISAM
tables.
It can have one of the following values to affect handling of
the DELAY_KEY_WRITE
table option that can
be used in CREATE TABLE
statements.
Option | Description |
---|---|
OFF | DELAY_KEY_WRITE is ignored. |
ON | MySQL honors any DELAY_KEY_WRITE option specified in
CREATE 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 all MyISAM
tables
by starting the server with the
--myisam-recover-options
option
(for example,
--myisam-recover-options=BACKUP,FORCE
).
See Section 5.1.3, “Server Command Options”, and
Section 14.3.1, “MyISAM
Startup Options”.
If you enable external locking with
--external-locking
, there is
no protection against index corruption for tables that use
delayed key writes.
Command-Line Format | --delayed_insert_limit=# | ||
Option-File Format | delayed_insert_limit | ||
Option Sets Variable | Yes, delayed_insert_limit | ||
Variable Name | delayed_insert_limit | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 100 | ||
Range | 1 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 100 | ||
Range | 1 .. 18446744073709547520 |
After inserting
delayed_insert_limit
delayed
rows into a nontransactional table, the
INSERT DELAYED
handler thread
checks whether there are any
SELECT
statements pending. If
so, it permits them to execute before continuing to insert
delayed rows.
Command-Line Format | --delayed_insert_timeout=# | ||
Option-File Format | delayed_insert_timeout | ||
Option Sets Variable | Yes, delayed_insert_timeout | ||
Variable Name | delayed_insert_timeout | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 300 |
How many seconds an INSERT
DELAYED
handler thread should wait for
INSERT
statements before
terminating.
Command-Line Format | --delayed_queue_size=# | ||
Option-File Format | delayed_queue_size | ||
Option Sets Variable | Yes, delayed_queue_size | ||
Variable Name | delayed_queue_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 1000 | ||
Range | 1 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1000 | ||
Range | 1 .. 18446744073709547520 |
This is a per-table limit on the number of rows to queue when
handling INSERT DELAYED
statements for nontransactional tables. If the queue becomes
full, any client that issues an INSERT
DELAYED
statement waits until there is room in the
queue again.
Command-Line Format | --div_precision_increment=# | ||
Option-File Format | div_precision_increment | ||
Option Sets Variable | Yes, div_precision_increment | ||
Variable Name | div_precision_increment | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 4 | ||
Range | 0 .. 30 |
This variable indicates the number of digits by which to
increase the scale of the result of division operations
performed with the
/
operator.
The default value is 4. The minimum and maximum values are 0
and 30, respectively. The following example illustrates the
effect of increasing the default value.
mysql>SELECT 1/7;
+--------+ | 1/7 | +--------+ | 0.1429 | +--------+ mysql>SET div_precision_increment = 12;
mysql>SELECT 1/7;
+----------------+ | 1/7 | +----------------+ | 0.142857142857 | +----------------+
Version Removed | 5.6.1 | ||
Command-Line Format | --engine-condition-pushdown | ||
Option-File Format | engine-condition-pushdown | ||
Option Sets Variable | Yes, engine_condition_pushdown | ||
Variable Name | engine_condition_pushdown | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Deprecated | 5.5.3, by optimizer_switch | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
This variable was removed in MySQL 5.6.1. Use the
engine_condition_pushdown
flag of the
optimizer_switch
variable
instead. See Section 8.8.5.2, “Controlling Switchable Optimizations”.
Version Introduced | 5.6.5 | ||
Variable Name | end_markers_in_json | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Whether optimizer JSON output should add end markers.
Version Introduced | 5.6.5 | ||
Command-Line Format | --eq_range_index_dive_limit=# | ||
Option-File Format | eq_range_index_dive_limit | ||
Option Sets Variable | Yes, eq_range_index_dive_limit | ||
Variable Name | eq_range_index_dive_limit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 10 | ||
Range | 0 .. 4294967295 |
This variable indicates the number of equality ranges in an
equality comparison condition when the optimizer should switch
from using index dives to index statistics in estimating the
number of qualifying rows. It applies to evaluation of
expressions that have either of these equivalent forms, where
the optimizer uses a nonunique index to look up
col_name
values:
col_name
IN(val1
, ...,valN
)col_name
=val1
OR ... ORcol_name
=valN
In both cases, the expression contains
N
equality ranges. The optimizer
can make row estimates using index dives or index statistics.
If eq_range_index_dive_limit
is greater than 0, the optimizer uses existing index
statistics instead of index dives if there are
eq_range_index_dive_limit
or
more equality ranges. Thus, to permit use of index dives for
up to N
equality ranges, set
eq_range_index_dive_limit
to
N
+ 1. Set
eq_range_index_dive_limit
to
0 to disable use of index statistics and always use index
dives regardless of N
.
For more information, see Section 8.13.1.3, “Equality Range Optimization of Many-Valued Comparisons”.
This variable was added in MySQL 5.6.5. Before 5.6.5, the optimizer makes row estimates using index dives in all cases.
To update table index statistics for best estimates, use
ANALYZE TABLE
.
The number of errors that resulted from the last statement
that generated messages. This variable is read only. See
Section 13.7.5.18, “SHOW ERRORS
Syntax”.
Command-Line Format | --event-scheduler[=value] | ||
Option-File Format | event-scheduler | ||
Option Sets Variable | Yes, event_scheduler | ||
Variable Name | event_scheduler | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | OFF | ||
Valid Values |
|
This variable indicates the status of the Event Scheduler;
possible values are ON
,
OFF
, and DISABLED
, with
the default being OFF
. This variable and
its effects on the Event Scheduler's operation are discussed
in greater detail in the
Overview section
of the Events chapter.
Command-Line Format | --expire_logs_days=# | ||
Option-File Format | expire_logs_days | ||
Option Sets Variable | Yes, expire_logs_days | ||
Variable Name | expire_logs_days | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 99 |
The number of days for automatic binary log file removal. The default is 0, which means “no automatic removal.” Possible removals happen at startup and when the binary log is flushed. Log flushing occurs as indicated in Section 5.2, “MySQL Server Logs”.
To remove binary log files manually, use the
PURGE BINARY LOGS
statement.
See Section 13.4.1.1, “PURGE BINARY LOGS
Syntax”.
explicit_defaults_for_timestamp
Version Introduced | 5.6.6 | ||
Command-Line Format | --explicit_defaults_for_timestamp=# | ||
Option-File Format | explicit_defaults_for_timestamp | ||
Option Sets Variable | Yes, explicit_defaults_for_timestamp | ||
Variable Name | explicit_defaults_for_timestamp | ||
Variable Scope | Session | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
In MySQL, the TIMESTAMP
data
type differs in nonstandard ways from other data types:
TIMESTAMP
columns not
explicitly declared with the NULL
attribute are assigned the NOT NULL
attribute. (Columns of other data types, if not explicitly
declared as NOT NULL
, permit
NULL
values.) Setting such a column to
NULL
sets it to the current timestamp.
The first TIMESTAMP
column
in a table, if not declared with the
NULL
attribute or an explicit
DEFAULT
or ON UPDATE
clause, is automatically assigned the DEFAULT
CURRENT_TIMESTAMP
and ON UPDATE
CURRENT_TIMESTAMP
attributes.
TIMESTAMP
columns following
the first one, if not declared with the
NULL
attribute or an explicit
DEFAULT
clause, are automatically
assigned DEFAULT '0000-00-00 00:00:00'
(the “zero” timestamp). For inserted rows
that specify no explicit value for such a column, the
column is assigned '0000-00-00
00:00:00'
and no warning occurs.
Those nonstandard behaviors remain the default for
TIMESTAMP
but as of MySQL 5.6.6
are deprecated and this warning appears at startup:
[Warning] TIMESTAMP with implicit DEFAULT value is deprecated. Please use --explicit_defaults_for_timestamp server option (see documentation for more details).
As indicated by the warning, to turn off the nonstandard
behaviors, enable the new
explicit_defaults_for_timestamp
system variable at server startup. With this variable enabled,
the server handles TIMESTAMP
as
follows instead:
TIMESTAMP
columns not
explicitly declared as NOT NULL
permit
NULL
values. Setting such a column to
NULL
sets it to
NULL
, not the current timestamp.
No TIMESTAMP
column is
assigned the DEFAULT CURRENT_TIMESTAMP
or ON UPDATE CURRENT_TIMESTAMP
attributes automatically. Those attributes must be
explicitly specified.
TIMESTAMP
columns declared
as NOT NULL
and without an explicit
DEFAULT
clause are treated as having no
default value. For inserted rows that specify no explicit
value for such a column, the result depends on the SQL
mode. If strict SQL mode is enabled, an error occurs. If
strict SQL mode is not enabled, the column is assigned the
implicit default of '0000-00-00
00:00:00'
and a warning occurs. This is similar
to how MySQL treats other temporal types such as
DATETIME
.
This variable was added in MySQL 5.6.6.
Variable Name | external_user | ||
Variable Scope | Session | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The external user name used during the authentication process,
as set by the plugin used to authenticate the client. With
native (built-in) MySQL authentication, or if the plugin does
not set the value, this variable is NULL
.
See Section 6.3.7, “Proxy Users”.
Command-Line Format | --flush | ||
Option-File Format | flush | ||
Variable Name | flush | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
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 C.5.4.2, “What to Do If MySQL Keeps Crashing”. This
variable is set to ON
if you start
mysqld with the
--flush
option.
Command-Line Format | --flush_time=# | ||
Option-File Format | flush_time | ||
Option Sets Variable | Yes, flush_time | ||
Variable Name | flush_time | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Type (windows) | numeric | ||
Default | 1800 | ||
Min Value | 0 | ||
Permitted Values (>= 5.6.6) | |||
Type (windows) | numeric | ||
Default | 0 | ||
Min Value | 0 |
If this is set to a nonzero value, all tables are closed every
flush_time
seconds to free up
resources and synchronize unflushed data to disk. This option
is best used only on systems with minimal resources. The
default is 0 except that before MySQL 5.6.6, the default is
1800 on Windows.
If set to 1 (the default),
foreign key
constraints for InnoDB
tables are checked.
If set to 0, they are ignored. Typically you leave this
setting enabled during normal operation, to enforce
referential
integrity. Disabling foreign key checking can be useful
for reloading InnoDB
tables in an order
different from that required by their parent/child
relationships. See
Section 14.2.2.5, “FOREIGN KEY
Constraints”.
Setting foreign_key_checks
to 0 also
affects data definition statements:
DROP
SCHEMA
drops a schema even if it contains tables
that have foreign keys that are referred to by tables outside
the schema, and DROP TABLE
drops tables that have foreign keys that are referred to by
other tables.
Setting foreign_key_checks
to 1 does not
trigger a scan of the existing table data. Therefore, rows
added to the table while
foreign_key_checks = 0
will
not be verified for consistency.
Command-Line Format | --ft_boolean_syntax=name | ||
Option-File Format | ft_boolean_syntax | ||
Variable Name | ft_boolean_syntax | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string | ||
Default | +-><()~*:""& |
The list of operators supported by boolean full-text searches
performed using IN BOOLEAN MODE
. See
Section 12.9.2, “Boolean Full-Text Searches”.
The default variable value is
'+ -><()~*:""&|'
. The rules
for changing the value are as follows:
Operator function is determined by position within the string.
The replacement value must be 14 characters.
Each character must be an ASCII nonalphanumeric character.
Either the first or second character must be a space.
No duplicates are permitted except the phrase quoting operators in positions 11 and 12. These two characters are not required to be the same, but they are the only two that may be.
Positions 10, 13, and 14 (which by default are set to
“:
”,
“&
”, and
“|
”) are reserved for
future extensions.
Command-Line Format | --ft_max_word_len=# | ||
Option-File Format | ft_max_word_len | ||
Option Sets Variable | Yes, ft_max_word_len | ||
Variable Name | ft_max_word_len | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Min Value | 10 |
The maximum length of the word to be included in a
MyISAM
FULLTEXT
index.
FULLTEXT
indexes on
MyISAM
tables must be rebuilt after
changing this variable. Use REPAIR TABLE
.
tbl_name
QUICK
Command-Line Format | --ft_min_word_len=# | ||
Option-File Format | ft_min_word_len | ||
Option Sets Variable | Yes, ft_min_word_len | ||
Variable Name | ft_min_word_len | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 4 | ||
Min Value | 1 |
The minimum length of the word to be included in a
MyISAM
FULLTEXT
index.
FULLTEXT
indexes on
MyISAM
tables must be rebuilt after
changing this variable. Use REPAIR TABLE
.
tbl_name
QUICK
Command-Line Format | --ft_query_expansion_limit=# | ||
Option-File Format | ft_query_expansion_limit | ||
Option Sets Variable | Yes, ft_query_expansion_limit | ||
Variable Name | ft_query_expansion_limit | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 20 | ||
Range | 0 .. 1000 |
The number of top matches to use for full-text searches
performed using WITH QUERY EXPANSION
.
Command-Line Format | --ft_stopword_file=file_name | ||
Option-File Format | ft_stopword_file=file_name | ||
Option Sets Variable | Yes, ft_stopword_file | ||
Variable Name | ft_stopword_file | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The file from which to read the list of stopwords for
full-text searches on MyISAM
tables. The
server looks for the file in the data directory unless an
absolute path name is given to specify a different directory.
All the words from the file are used; comments are
not honored. By default, a built-in list
of stopwords is used (as defined in the
storage/myisam/ft_static.c
file). Setting
this variable to the empty string (''
)
disables stopword filtering. See also
Section 12.9.4, “Full-Text Stopwords”.
FULLTEXT
indexes on
MyISAM
tables must be rebuilt after
changing this variable or the contents of the stopword file.
Use REPAIR TABLE
.
tbl_name
QUICK
Command-Line Format | --general-log | ||
Option-File Format | general-log | ||
Option Sets Variable | Yes, general_log | ||
Variable Name | general_log | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Whether the general query log is enabled. The value can be 0
(or OFF
) to disable the log or 1 (or
ON
) to enable the log. The default value
depends on whether the
--general_log
option is given.
The destination for log output is controlled by the
log_output
system variable;
if that value is NONE
, no log entries are
written even if the log is enabled.
Command-Line Format | --general-log-file=file_name | ||
Option-File Format | general_log_file | ||
Option Sets Variable | Yes, general_log_file | ||
Variable Name | general_log_file | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | file name | ||
Default | host_name.log |
The name of the general query log file. The default value is
,
but the initial value can be changed with the
host_name
.log--general_log_file
option.
Command-Line Format | --group_concat_max_len=# | ||
Option-File Format | group_concat_max_len | ||
Option Sets Variable | Yes, group_concat_max_len | ||
Variable Name | group_concat_max_len | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 1024 | ||
Range | 4 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1024 | ||
Range | 4 .. 18446744073709547520 |
The maximum permitted result length in bytes for the
GROUP_CONCAT()
function. The
default is 1024.
YES
if the zlib
compression library is available to the server,
NO
if not. If not, the
COMPRESS()
and
UNCOMPRESS()
functions cannot
be used.
YES
if the crypt()
system call is available to the server, NO
if not. If not, the ENCRYPT()
function cannot be used.
YES
if mysqld supports
CSV
tables, NO
if not.
This variable was removed in MySQL 5.6.1. Use
SHOW ENGINES
instead.
YES
if mysqld supports
dynamic loading of plugins, NO
if not.
YES
if the server supports spatial data
types, NO
if not.
YES
if mysqld supports
InnoDB
tables. DISABLED
if
--skip-innodb
is used.
This variable was removed in MySQL 5.6.1. Use
SHOW ENGINES
instead.
This variable is an alias for
have_ssl
.
YES
if mysqld supports
partitioning.
This variable was removed in MySQL 5.6.1. Use
SHOW ENGINES
instead.
YES
if statement profiling capability is
present, NO
if not. If present, the
profiling
system variable controls whether
this capability is enabled or disabled. See
Section 13.7.5.32, “SHOW PROFILES
Syntax”.
This variable is deprecated in MySQL 5.6.8 and will be removed in a future MySQL release.
YES
if mysqld supports
the query cache, NO
if not.
YES
if RTREE
indexes are
available, NO
if not. (These are used for
spatial indexes in MyISAM
tables.)
YES
if mysqld supports
SSL connections, NO
if not.
DISABLED
indicates that the server was
compiled with SSL support, but but was not started with the
appropriate
--ssl-
options.
For more information, see
Section 6.3.8.2, “Configuring MySQL for SSL”.
xxx
YES
if symbolic link support is enabled,
NO
if not. This is required on Unix for
support of the DATA DIRECTORY
and
INDEX DIRECTORY
table options, and on
Windows for support of data directory symlinks. If the server
is started with the
--skip-symbolic-links
option, the value is DISABLED
.
Version Introduced | 5.6.5 | ||
Command-Line Format | --host_cache_size=# | ||
Option-File Format | host_cache_size | ||
Option Sets Variable | Yes, host_cache_size | ||
Variable Name | host_cache_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.7) | |||
Type | numeric | ||
Default | 128 | ||
Range | 0 .. 65536 | ||
Permitted Values (>= 5.6.8) | |||
Type | numeric | ||
Default | -1 (autosized) | ||
Range | 0 .. 65536 |
The size of the internal host cache (see
Section 8.11.5.2, “DNS Lookup Optimization and the Host Cache”). Setting the size to 0 disables
the host cache. Changing the cache size at runtime implicitly
causes a FLUSH
HOSTS
operation to clear the host cache and truncate
the host_cache
table.
The default value is 128, plus 1 for a value of
max_connections
up to 500,
plus 1 for every increment of 20 over 500 in the
max_connections
value, capped
to a limit of 2000. Before MySQL 5.6.8, the default is 128.
Use of --skip-host-cache
is
similar to setting the
host_cache_size
system
variable to 0, but
host_cache_size
is more
flexible because it can also be used to resize, enable, or
disable the host cache at runtime, not just at server startup.
If you start the server with
--skip-host-cache
, the host
cache cannot be re-enabled at runtime.
This variable was added in MySQL 5.6.5.
Variable Name | hostname | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The server sets this variable to the server host name at startup.
This variable is a synonym for the
last_insert_id
variable. It
exists for compatibility with other database systems. You can
read its value with SELECT @@identity
, and
set it using SET identity
.
Version Introduced | 5.6.3 | ||
Variable Name | ignore_db_dirs | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
A comma-separated list of names that are not considered as
database directories in the data directory. The value is set
from any instances of
--ignore-db-dir
given at server
startup.
This variable was added in MySQL 5.6.3.
Command-Line Format | --init-connect=name | ||
Option-File Format | init_connect | ||
Option Sets Variable | Yes, init_connect | ||
Variable Name | init_connect | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
A string to be executed by the server for each client that
connects. The string consists of one or more SQL statements,
separated by semicolon characters. For example, each client
session begins by default with autocommit mode enabled. For
older servers (before MySQL 5.5.8), there is no global
autocommit
system variable to
specify that autocommit should be disabled by default, but as
a workaround init_connect
can
be used to achieve the same effect:
SET GLOBAL init_connect='SET autocommit=0';
The init_connect
variable can
also be set on the command line or in an option file. To set
the variable as just shown using an option file, include these
lines:
[mysqld] init_connect='SET autocommit=0'
The content of init_connect
is not executed for users that have the
SUPER
privilege. This is done
so that an erroneous value for
init_connect
does not prevent
all clients from connecting. For example, the value might
contain a statement that has a syntax error, thus causing
client connections to fail. Not executing
init_connect
for users that
have the SUPER
privilege
enables them to open a connection and fix the
init_connect
value.
Command-Line Format | --init-file=file_name | ||
Option-File Format | init-file=file_name | ||
Option Sets Variable | Yes, init_file | ||
Variable Name | init_file | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The name of the file specified with the
--init-file
option when you
start the server. This should be a file containing SQL
statements that you want the server to execute when it starts.
Each statement must be on a single line and should not include
comments. No statement terminator such as
;
, \g
, or
\G
should be given at the end of each
statement.
Note that the --init-file
option is unavailable if MySQL was configured with the
DISABLE_GRANT_OPTIONS
compiler
flag. See Section 2.9.4, “MySQL Source-Configuration Options”.
innodb_
xxx
InnoDB
system variables are
listed in Section 14.2.7, “InnoDB
Startup Options and System Variables”. These variables
control many aspects of storage, memory use, and I/O patterns
for InnoDB
tables, and are especially
important now that InnoDB is
the default storage engine.
The value to be used by the following
INSERT
or
ALTER TABLE
statement when
inserting an AUTO_INCREMENT
value. This is
mainly used with the binary log.
Command-Line Format | --interactive_timeout=# | ||
Option-File Format | interactive_timeout | ||
Option Sets Variable | Yes, interactive_timeout | ||
Variable Name | interactive_timeout | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 28800 | ||
Min Value | 1 |
The number of seconds the server waits for activity on an
interactive connection before closing it. An interactive
client is defined as a client that uses the
CLIENT_INTERACTIVE
option to
mysql_real_connect()
. See also
wait_timeout
.
Command-Line Format | --join_buffer_size=# | ||
Option-File Format | join_buffer_size | ||
Option Sets Variable | Yes, join_buffer_size | ||
Variable Name | join_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 131072 | ||
Range | 8200 .. 18446744073709547520 | ||
Permitted Values (<= 5.6.5) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 131072 | ||
Range | 8200 .. 4294967295 | ||
Permitted Values (>= 5.6.6) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 262144 | ||
Range | 8200 .. 4294967295 | ||
Permitted Values (>= 5.6.6) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 262144 | ||
Range | 128 .. 18446744073709547520 |
The minimum size of the buffer that is used for plain index
scans, range index scans, and joins that do not use indexes
and thus perform full table scans. Normally, the best way to
get fast joins is to add indexes. Increase the value of
join_buffer_size
to get a
faster full join when adding indexes is not possible. One join
buffer is allocated for each full join between two tables. For
a complex join between several tables for which indexes are
not used, multiple join buffers might be necessary. There is
no gain from setting the buffer larger than required to hold
each matching row, and all joins allocate at least the minimum
size, so use caution in setting this variable to a large value
globally. It is better to keep the global setting small and
change to a larger setting only in sessions that are doing
large joins. Memory allocation time can cause substantial
performance drops if the global size is larger than needed by
most queries that use it.
The default is 256KB as of MySQL 5.6.6, 128KB before that. The
maximum permissible setting for
join_buffer_size
is 4GB.
Values larger than 4GB are permitted for 64-bit platforms
(except 64-bit Windows, for which large values are truncated
to 4GB with a warning).
Command-Line Format | --keep_files_on_create=# | ||
Option-File Format | keep_files_on_create | ||
Option Sets Variable | Yes, keep_files_on_create | ||
Variable Name | keep_files_on_create | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
If a MyISAM
table is created with no
DATA DIRECTORY
option, the
.MYD
file is created in the database
directory. By default, if MyISAM
finds an
existing .MYD
file in this case, it
overwrites it. The same applies to .MYI
files for tables created with no INDEX
DIRECTORY
option. To suppress this behavior, set the
keep_files_on_create
variable
to ON
(1), in which case
MyISAM
will not overwrite existing files
and returns an error instead. The default value is
OFF
(0).
If a MyISAM
table is created with a
DATA DIRECTORY
or INDEX
DIRECTORY
option and an existing
.MYD
or .MYI
file is
found, MyISAM always returns an error. It will not overwrite a
file in the specified directory.
Command-Line Format | --key_buffer_size=# | ||
Option-File Format | key_buffer_size | ||
Option Sets Variable | Yes, key_buffer_size | ||
Variable Name | key_buffer_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 8388608 | ||
Range | 8 .. 4294967295 |
Index blocks for MyISAM
tables are buffered
and are shared by all threads.
key_buffer_size
is the size
of the buffer used for index blocks. The key buffer is also
known as the key cache.
The maximum permissible setting for
key_buffer_size
is 4GB on
32-bit platforms. Values larger than 4GB are permitted for
64-bit platforms. The effective maximum size might be less,
depending on your available physical RAM and per-process RAM
limits imposed by your operating system or hardware platform.
The value of this variable indicates the amount of memory
requested. Internally, the server allocates as much memory as
possible up to this amount, but the actual allocation might be
less.
You can increase the value to get better index handling for
all reads and multiple writes; on a system whose primary
function is to run MySQL using the
MyISAM
storage engine, 25% of the
machine's total memory is an acceptable value for this
variable. However, you should be aware that, if you make the
value too large (for example, more than 50% of the
machine's total memory), your system might start to page
and become extremely slow. This is because MySQL relies on the
operating system to perform file system caching for data
reads, so you must leave some room for the file system cache.
You should also consider the memory requirements of any other
storage engines that you may be using in addition to
MyISAM
.
For even more speed when writing many rows at the same time,
use LOCK TABLES
. See
Section 8.2.2.1, “Speed of INSERT
Statements”.
You can check the performance of the key buffer by issuing a
SHOW STATUS
statement and
examining the
Key_read_requests
,
Key_reads
,
Key_write_requests
, and
Key_writes
status variables.
(See Section 13.7.5, “SHOW
Syntax”.) The
Key_reads/Key_read_requests
ratio should
normally be less than 0.01. The
Key_writes/Key_write_requests
ratio is
usually near 1 if you are using mostly updates and deletes,
but might be much smaller if you tend to do updates that
affect many rows at the same time or if you are using the
DELAY_KEY_WRITE
table option.
The fraction of the key buffer in use can be determined using
key_buffer_size
in
conjunction with the
Key_blocks_unused
status
variable and the buffer block size, which is available from
the key_cache_block_size
system variable:
1 - ((Key_blocks_unused * key_cache_block_size) / key_buffer_size)
This value is an approximation because some space in the key buffer is allocated internally for administrative structures. Factors that influence the amount of overhead for these structures include block size and pointer size. As block size increases, the percentage of the key buffer lost to overhead tends to decrease. Larger blocks results in a smaller number of read operations (because more keys are obtained per read), but conversely an increase in reads of keys that are not examined (if not all keys in a block are relevant to a query).
It is possible to create multiple MyISAM
key caches. The size limit of 4GB applies to each cache
individually, not as a group. See
Section 8.9.2, “The MyISAM
Key Cache”.
Command-Line Format | --key_cache_age_threshold=# | ||
Option-File Format | key_cache_age_threshold | ||
Option Sets Variable | Yes, key_cache_age_threshold | ||
Variable Name | key_cache_age_threshold | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 300 | ||
Range | 100 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 300 | ||
Range | 100 .. 18446744073709547520 |
This value controls the demotion of buffers from the hot
sublist of a key cache to the warm sublist. Lower values cause
demotion to happen more quickly. The minimum value is 100. The
default value is 300. See Section 8.9.2, “The MyISAM
Key Cache”.
Command-Line Format | --key_cache_block_size=# | ||
Option-File Format | key_cache_block_size | ||
Option Sets Variable | Yes, key_cache_block_size | ||
Variable Name | key_cache_block_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 1024 | ||
Range | 512 .. 16384 |
The size in bytes of blocks in the key cache. The default
value is 1024. See Section 8.9.2, “The MyISAM
Key Cache”.
Command-Line Format | --key_cache_division_limit=# | ||
Option-File Format | key_cache_division_limit | ||
Option Sets Variable | Yes, key_cache_division_limit | ||
Variable Name | key_cache_division_limit | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 100 | ||
Range | 1 .. 100 |
The division point between the hot and warm sublists of the
key cache buffer list. The value is the percentage of the
buffer list to use for the warm sublist. Permissible values
range from 1 to 100. The default value is 100. See
Section 8.9.2, “The MyISAM
Key Cache”.
Variable Name | large_files_support | ||
Variable Scope | Global | ||
Dynamic Variable | No |
Whether mysqld was compiled with options for large file support.
Command-Line Format | --large-pages | ||
Option-File Format | large-pages | ||
Option Sets Variable | Yes, large_pages | ||
Variable Name | large_pages | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Platform Specific | linux | ||
Permitted Values | |||
Type (linux) | boolean | ||
Default | FALSE |
Whether large page support is enabled (via the
--large-pages
option). See
Section 8.11.4.2, “Enabling Large Page Support”.
Variable Name | large_page_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type (linux) | numeric | ||
Default | 0 |
If large page support is enabled, this shows the size of memory pages. Currently, large memory pages are supported only on Linux; on other platforms, the value of this variable is always 0. See Section 8.11.4.2, “Enabling Large Page Support”.
The value to be returned from
LAST_INSERT_ID()
. This is
stored in the binary log when you use
LAST_INSERT_ID()
in a statement
that updates a table. Setting this variable does not update
the value returned by the
mysql_insert_id()
C API
function.
Command-Line Format | --lc-messages=name | ||
Option-File Format | lc-messages | ||
Option Sets Variable | Yes, lc_messages | ||
Variable Name | lc-messages | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The locale to use for error messages. The server converts the
value to a language name and combines it with the value of the
lc_messages_dir
to produce
the location for the error message file. See
Section 10.2, “Setting the Error Message Language”.
Command-Line Format | --lc-messages-dir=path | ||
Option-File Format | lc-messages-dir | ||
Option Sets Variable | Yes, lc_messages_dir | ||
Variable Name | lc-messages-dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name |
The directory where error messages are located. The value is
used together with the value of
lc_messages
to produce the
location for the error message file. See
Section 10.2, “Setting the Error Message Language”.
Variable Name | lc_time_names | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
This variable specifies the locale that controls the language
used to display day and month names and abbreviations. This
variable affects the output from the
DATE_FORMAT()
,
DAYNAME()
and
MONTHNAME()
functions. Locale
names are POSIX-style values such as
'ja_JP'
or 'pt_BR'
. The
default value is 'en_US'
regardless of your
system's locale setting. For further information, see
Section 10.7, “MySQL Server Locale Support”.
Variable Name | license | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string | ||
Default | GPL |
The type of license the server has.
Variable Name | local_infile | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean |
Whether LOCAL
is supported for
LOAD DATA
INFILE
statements. If this variable is disabled,
clients cannot use LOCAL
in
LOAD DATA
statements. See
Section 6.1.6, “Security Issues with LOAD
DATA LOCAL
”.
Command-Line Format | --lock_wait_timeout=# | ||
Option-File Format | lock_wait_timeout | ||
Option Sets Variable | Yes, lock_wait_timeout | ||
Variable Name | lock_wait_timeout | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 31536000 | ||
Range | 1 .. 31536000 |
This variable specifies the timeout in seconds for attempts to acquire metadata locks. The permissible values range from 1 to 31536000 (1 year). The default is 31536000.
This timeout applies to all statements that use metadata
locks. These include DML and DDL operations on tables, views,
stored procedures, and stored functions, as well as
LOCK TABLES
,
FLUSH TABLES WITH READ
LOCK
, and HANDLER
statements.
This timeout does not apply to implicit accesses to system
tables in the mysql
database, such as grant
tables modified by GRANT
or
REVOKE
statements or table
logging statements. The timeout does apply to system tables
accessed directly, such as with
SELECT
or
UPDATE
.
The timeout value applies separately for each metadata lock
attempt. A given statement can require more than one lock, so
it is possible for the statement to block for longer than the
lock_wait_timeout
value
before reporting a timeout error. When lock timeout occurs,
ER_LOCK_WAIT_TIMEOUT
is
reported.
lock_wait_timeout
does not
apply to delayed inserts, which always execute with a timeout
of 1 year. This is done to avoid unnecessary timeouts because
a session that issues a delayed insert receives no
notification of delayed insert timeouts.
Variable Name | locked_in_memory | ||
Variable Scope | Global | ||
Dynamic Variable | No |
This variable removed in MySQL 5.6.1. Use
general_log
instead.
Variable Name | log_bin | ||
Variable Scope | Global | ||
Dynamic Variable | No |
Whether the binary log is enabled. If the
--log-bin
option is used, then
the value of this variable is ON
; otherwise
it is OFF
. This variable reports only on
the status of binary logging (enabled or disabled); it does
not actually report the value to which
--log-bin
is set.
log_bin_trust_function_creators
Command-Line Format | --log-bin-trust-function-creators | ||
Option-File Format | log-bin-trust-function-creators | ||
Option Sets Variable | Yes, log_bin_trust_function_creators | ||
Variable Name | log_bin_trust_function_creators | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
This variable applies when binary logging is enabled. It
controls whether stored function creators can be trusted not
to create stored functions that will cause unsafe events to be
written to the binary log. If set to 0 (the default), users
are not permitted to create or alter stored functions unless
they have the SUPER
privilege
in addition to the CREATE
ROUTINE
or ALTER
ROUTINE
privilege. A setting of 0 also enforces the
restriction that a function must be declared with the
DETERMINISTIC
characteristic, or with the
READS SQL DATA
or NO SQL
characteristic. If the variable is set to 1, MySQL does not
enforce these restrictions on stored function creation. This
variable also applies to trigger creation. See
Section 18.7, “Binary Logging of Stored Programs”.
Command-Line Format | --log-error[=name] | ||
Option-File Format | log-error | ||
Option Sets Variable | Yes, log_error | ||
Variable Name | log_error | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The location of the error log.
Command-Line Format | --log-output=name | ||
Option-File Format | log-output | ||
Option Sets Variable | Yes, log_output | ||
Variable Name | log_output | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | set | ||
Default | FILE | ||
Valid Values |
|
The destination for general query log and slow query log
output. The value can be a comma-separated list of one or more
of the words TABLE
(log to tables),
FILE
(log to files), or
NONE
(do not log to tables or files). The
default value is FILE
.
NONE
, if present, takes precedence over any
other specifiers. If the value is NONE
log
entries are not written even if the logs are enabled. If the
logs are not enabled, no logging occurs even if the value of
log_output
is not
NONE
. For more information, see
Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”.
Command-Line Format | --log-queries-not-using-indexes | ||
Option-File Format | log-queries-not-using-indexes | ||
Option Sets Variable | Yes, log_queries_not_using_indexes | ||
Variable Name | log_queries_not_using_indexes | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Whether queries that do not use indexes are logged to the slow query log. See Section 5.2.5, “The Slow Query Log”.
Version Removed | 5.6.1 | ||
Command-Line Format | --log-slow-queries[=name] | ||
Option-File Format | log-slow-queries | ||
Option Sets Variable | Yes, log_slow_queries | ||
Variable Name | log_slow_queries | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Deprecated | 5.1.29, by slow-query-log | ||
Permitted Values | |||
Type | boolean |
This variable was removed in MySQL 5.6.1. Use
slow_query_log
instead.
log_throttle_queries_not_using_indexes
Version Introduced | 5.6.5 | ||
Variable Name | log_throttle_queries_not_using_indexes | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 |
If
log_queries_not_using_indexes
is enabled, the
log_throttle_queries_not_using_indexes
variable limits the number of such queries per minute that can
be written to the slow query log. A value of 0 (the default)
means “no limit”. For more information, see
Section 5.2.5, “The Slow Query Log”.
This variable was added in MySQL 5.6.5.
Command-Line Format | --log-warnings[=#] | ||
-W [#] | |||
Option-File Format | log-warnings | ||
Option Sets Variable | Yes, log_warnings | ||
Variable Name | log_warnings | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Disabled by | skip-log-warnings | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1 | ||
Range | 0 .. 18446744073709547520 |
Whether to produce additional warning messages to the error log. It is enabled (1) by default and can be disabled by setting it to 0. Aborted connections and access-denied errors for new connection attempts are logged if the value is greater than 1. The server logs messages about statements that are unsafe for statement-based logging only if the value is greater than 0.
Command-Line Format | --long_query_time=# | ||
Option-File Format | long_query_time | ||
Option Sets Variable | Yes, long_query_time | ||
Variable Name | long_query_time | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 10 | ||
Min Value | 0 |
If a query takes longer than this many seconds, the server
increments the Slow_queries
status variable. If the slow query log is enabled, the query
is logged to the slow query log file. This value is measured
in real time, not CPU time, so a query that is under the
threshold on a lightly loaded system might be above the
threshold on a heavily loaded one. The minimum and default
values of long_query_time
are
0 and 10, respectively. The value can be specified to a
resolution of microseconds. For logging to a file, times are
written including the microseconds part. For logging to
tables, only integer times are written; the microseconds part
is ignored. See Section 5.2.5, “The Slow Query Log”.
Command-Line Format | --low-priority-updates | ||
Option-File Format | low-priority-updates | ||
Option Sets Variable | Yes, low_priority_updates | ||
Variable Name | low_priority_updates | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
If set to 1
, all
INSERT
,
UPDATE
,
DELETE
, and LOCK TABLE
WRITE
statements wait until there is no pending
SELECT
or LOCK TABLE
READ
on the affected table. This affects only
storage engines that use only table-level locking (such as
MyISAM
, MEMORY
, and
MERGE
).
Command-Line Format | --lower_case_file_system[=#] | ||
Option-File Format | lower_case_file_system | ||
Option Sets Variable | Yes, lower_case_file_system | ||
Variable Name | lower_case_file_system | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | boolean |
This variable describes the case sensitivity of file names on
the file system where the data directory is located.
OFF
means file names are case sensitive,
ON
means they are not case sensitive. This
variable is read only because it reflects a file system
attribute and setting it would have no effect on the file
system.
Command-Line Format | --lower_case_table_names[=#] | ||
Option-File Format | lower_case_table_names | ||
Option Sets Variable | Yes, lower_case_table_names | ||
Variable Name | lower_case_table_names | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 2 |
If set to 0, table names are stored as specified and comparisons are case sensitive. If set to 1, table names are stored in lowercase on disk and comparisons are not case sensitive. If set to 2, table names are stored as given but compared in lowercase. This option also applies to database names and table aliases. For additional information, see Section 9.2.2, “Identifier Case Sensitivity”.
You should not set this variable to 0 if
you are running MySQL on a system that has case-insensitive
file names (such as Windows or Mac OS X). If you set this
variable to 0 on such a system and access
MyISAM
tablenames using different
lettercases, index corruption may result. On Windows the
default value is 1. On Mac OS X, the default value is 2.
If you are using InnoDB
tables, you should
set this variable to 1 on all platforms to force names to be
converted to lowercase.
The setting of this variable in MySQL 5.6 affects the behavior of replication filtering options with regard to case sensitivity. This is a change from previous versions of MySQL. (Bug #51639) See Section 16.2.3, “How Servers Evaluate Replication Filtering Rules”, for more information.
In previous versions of MySQL, using different settings for
lower_case_table_names
on replication
masters and slaves could cause replication to fail when the
slave used a case-sensitive file system. This issue is
resolved in MySQL 5.6.1. For more information, see
Section 16.4.1.34, “Replication and Variables”.
Command-Line Format | --max_allowed_packet=# | ||
Option-File Format | max_allowed_packet | ||
Option Sets Variable | Yes, max_allowed_packet | ||
Variable Name | max_allowed_packet | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Type | numeric | ||
Default | 1048576 | ||
Range | 1024 .. 1073741824 | ||
Permitted Values (>= 5.6.6) | |||
Type | numeric | ||
Default | 4194304 | ||
Range | 1024 .. 1073741824 |
The maximum size of one packet or any generated/intermediate
string, or any parameter sent by the
mysql_stmt_send_long_data()
C
API function. The default is 4MB as of MySQL 5.6.6, 1MB before
that.
The packet message buffer is initialized to
net_buffer_length
bytes, but
can grow up to
max_allowed_packet
bytes when
needed. This value by default is small, to catch large
(possibly incorrect) packets.
You must increase this value if you are using large
BLOB
columns or long strings.
It should be as big as the largest
BLOB
you want to use. The
protocol limit for
max_allowed_packet
is 1GB.
The value should be a multiple of 1024; nonmultiples are
rounded down to the nearest multiple.
When you change the message buffer size by changing the value
of the max_allowed_packet
variable, you should also change the buffer size on the client
side if your client program permits it. On the client side,
max_allowed_packet
has a
default of 1GB. Some programs such as mysql
and mysqldump enable you to change the
client-side value by setting
max_allowed_packet
on the
command line or in an option file.
The session value of this variable is read only.
Command-Line Format | --max_connect_errors=# | ||
Option-File Format | max_connect_errors | ||
Option Sets Variable | Yes, max_connect_errors | ||
Variable Name | max_connect_errors | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 10 | ||
Range | 1 .. 4294967295 | ||
Permitted Values (<= 5.6.5) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 10 | ||
Range | 1 .. 18446744073709547520 | ||
Permitted Values (>= 5.6.6) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 100 | ||
Range | 1 .. 4294967295 | ||
Permitted Values (>= 5.6.6) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 100 | ||
Range | 1 .. 18446744073709547520 |
If more than this many successive connection requests from a
host are interrupted without a successful connection, the
server blocks that host from further connections. You can
unblock blocked hosts by flushing the host cache. To do so,
issue a FLUSH
HOSTS
statement or execute a mysqladmin
flush-hosts command. If a connection is established
successfully within fewer than
max_connect_errors
attempts
after a previous connection was interrupted, the error count
for the host is cleared to zero. However, once a host is
blocked, flushing the host cache is the only way to unblock
it. The default is 100 as of MySQL 5.6.6, 10 before that.
Command-Line Format | --max_connections=# | ||
Option-File Format | max_connections | ||
Option Sets Variable | Yes, max_connections | ||
Variable Name | max_connections | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 151 | ||
Range | 1 .. 100000 |
The maximum permitted number of simultaneous client
connections. By default, this is 151. See
Section C.5.2.7, “Too many connections
”, for more information.
Increasing this value increases the number of file descriptors that mysqld requires. See Section 8.4.3.1, “How MySQL Opens and Closes Tables”, for comments on file descriptor limits.
Connections refused because the
max_connections
limit is
reached increment the
Connection_errors_max_connections
status variable.
Command-Line Format | --max_delayed_threads=# | ||
Option-File Format | max_delayed_threads | ||
Option Sets Variable | Yes, max_delayed_threads | ||
Variable Name | max_delayed_threads | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 20 | ||
Range | 0 .. 16384 |
Do not start more than this number of threads to handle
INSERT DELAYED
statements for
nontransactional tables. If you try to insert data into a new
table after all INSERT DELAYED
threads are in use, the row is inserted as if the
DELAYED
attribute was not specified. If you
set this to 0, MySQL never creates a thread to handle
DELAYED
rows; in effect, this disables
DELAYED
entirely.
For the SESSION
value of this variable, the
only valid values are 0 or the GLOBAL
value.
Command-Line Format | --max_error_count=# | ||
Option-File Format | max_error_count | ||
Option Sets Variable | Yes, max_error_count | ||
Variable Name | max_error_count | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 64 | ||
Range | 0 .. 65535 |
The maximum number of error, warning, and note messages to be
stored for display by the SHOW
ERRORS
and SHOW
WARNINGS
statements. This is the same as the number
of condition areas in the diagnostics area, and thus the
number of conditions that can be inspected by
GET DIAGNOSTICS
.
Command-Line Format | --max_heap_table_size=# | ||
Option-File Format | max_heap_table_size | ||
Option Sets Variable | Yes, max_heap_table_size | ||
Variable Name | max_heap_table_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 16777216 | ||
Range | 16384 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 16777216 | ||
Range | 16384 .. 1844674407370954752 |
This variable sets the maximum size to which user-created
MEMORY
tables are permitted to grow. The
value of the variable is used to calculate
MEMORY
table MAX_ROWS
values. Setting this variable has no effect on any existing
MEMORY
table, unless the table is
re-created with a statement such as
CREATE TABLE
or altered with
ALTER TABLE
or
TRUNCATE TABLE
. A server
restart also sets the maximum size of existing
MEMORY
tables to the global
max_heap_table_size
value.
This variable is also used in conjunction with
tmp_table_size
to limit the
size of internal in-memory tables. See
Section 8.4.3.3, “How MySQL Uses Internal Temporary Tables”.
max_heap_table_size
is not replicated. See
Section 16.4.1.21, “Replication and MEMORY
Tables”, and
Section 16.4.1.34, “Replication and Variables”, for more
information.
Variable Name | max_insert_delayed_threads | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric |
This variable is a synonym for
max_delayed_threads
.
Command-Line Format | --max_join_size=# | ||
Option-File Format | max_join_size | ||
Option Sets Variable | Yes, max_join_size | ||
Variable Name | max_join_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 18446744073709551615 | ||
Range | 1 .. 18446744073709551615 |
Do not permit SELECT
statements
that probably need to examine more than
max_join_size
rows (for
single-table statements) or row combinations (for
multiple-table statements) or that are likely to do more than
max_join_size
disk seeks. By
setting this value, you can catch
SELECT
statements where keys
are not used properly and that would probably take a long
time. Set it if your users tend to perform joins that lack a
WHERE
clause, that take a long time, or
that return millions of rows.
Setting this variable to a value other than
DEFAULT
resets the value of
sql_big_selects
to
0
. If you set the
sql_big_selects
value again,
the max_join_size
variable is
ignored.
If a query result is in the query cache, no result size check is performed, because the result has previously been computed and it does not burden the server to send it to the client.
Command-Line Format | --max_length_for_sort_data=# | ||
Option-File Format | max_length_for_sort_data | ||
Option Sets Variable | Yes, max_length_for_sort_data | ||
Variable Name | max_length_for_sort_data | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 1024 | ||
Range | 4 .. 8388608 |
The cutoff on the size of index values that determines which
filesort
algorithm to use. See
Section 8.13.12, “ORDER BY
Optimization”.
Command-Line Format | --max_prepared_stmt_count=# | ||
Option-File Format | max_prepared_stmt_count | ||
Option Sets Variable | Yes, max_prepared_stmt_count | ||
Variable Name | max_prepared_stmt_count | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 16382 | ||
Range | 0 .. 1048576 |
This variable limits the total number of prepared statements in the server. (The sum of the number of prepared statements across all sessions.) It can be used in environments where there is the potential for denial-of-service attacks based on running the server out of memory by preparing huge numbers of statements. If the value is set lower than the current number of prepared statements, existing statements are not affected and can be used, but no new statements can be prepared until the current number drops below the limit. The default value is 16,382. The permissible range of values is from 0 to 1 million. Setting the value to 0 disables prepared statements.
Command-Line Format | --max_relay_log_size=# | ||
Option-File Format | max_relay_log_size | ||
Option Sets Variable | Yes, max_relay_log_size | ||
Variable Name | max_relay_log_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 1073741824 |
If a write by a replication slave to its relay log causes the
current log file size to exceed the value of this variable,
the slave rotates the relay logs (closes the current file and
opens the next one). If
max_relay_log_size
is 0, the
server uses max_binlog_size
for both the binary log and the relay log. If
max_relay_log_size
is greater
than 0, it constrains the size of the relay log, which enables
you to have different sizes for the two logs. You must set
max_relay_log_size
to between
4096 bytes and 1GB (inclusive), or to 0. The default value is
0. See Section 16.2.1, “Replication Implementation Details”.
Command-Line Format | --max_seeks_for_key=# | ||
Option-File Format | max_seeks_for_key | ||
Option Sets Variable | Yes, max_seeks_for_key | ||
Variable Name | max_seeks_for_key | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 4294967295 | ||
Range | 1 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 18446744073709547520 | ||
Range | 1 .. 18446744073709547520 |
Limit the assumed maximum number of seeks when looking up rows
based on a key. The MySQL optimizer assumes that no more than
this number of key seeks are required when searching for
matching rows in a table by scanning an index, regardless of
the actual cardinality of the index (see
Section 13.7.5.23, “SHOW INDEX
Syntax”). By setting this to a low value
(say, 100), you can force MySQL to prefer indexes instead of
table scans.
Command-Line Format | --max_sort_length=# | ||
Option-File Format | max_sort_length | ||
Option Sets Variable | Yes, max_sort_length | ||
Variable Name | max_sort_length | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 1024 | ||
Range | 4 .. 8388608 |
The number of bytes to use when sorting data values. Only the
first max_sort_length
bytes
of each value are used; the rest are ignored.
As of MySQL 5.6.9,
max_sort_length
is ignored
for integer, decimal, floating-point, and temporal data types.
Command-Line Format | --max_sp_recursion_depth[=#] | ||
Option-File Format | max_sp_recursion_depth | ||
Option Sets Variable | Yes, max_sp_recursion_depth | ||
Variable Name | max_sp_recursion_depth | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Max Value | 255 |
The number of times that any given stored procedure may be called recursively. The default value for this option is 0, which completely disables recursion in stored procedures. The maximum value is 255.
Stored procedure recursion increases the demand on thread
stack space. If you increase the value of
max_sp_recursion_depth
, it
may be necessary to increase thread stack size by increasing
the value of thread_stack
at
server startup.
This variable is unused. It is deprecated as of MySQL 5.6.7 and will be removed in a future MySQL release.
Command-Line Format | --max_user_connections=# | ||
Option-File Format | max_user_connections | ||
Option Sets Variable | Yes, max_user_connections | ||
Variable Name | max_user_connections | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 |
The maximum number of simultaneous connections permitted to any given MySQL user account. A value of 0 (the default) means “no limit.”
This variable has a global value that can be set at server startup or runtime. It also has a read-only session value that indicates the effective simultaneous-connection limit that applies to the account associated with the current session. The session value is initialized as follows:
If the user account has a nonzero
MAX_USER_CONNECTIONS
resource limit,
the session
max_user_connections
value is set to that limit.
Otherwise, the session
max_user_connections
value is set to the global value.
Account resource limits are specified using the
GRANT
statement. See
Section 6.3.4, “Setting Account Resource Limits”, and Section 13.7.1.4, “GRANT
Syntax”.
Command-Line Format | --max_write_lock_count=# | ||
Option-File Format | max_write_lock_count | ||
Option Sets Variable | Yes, max_write_lock_count | ||
Variable Name | max_write_lock_count | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 4294967295 | ||
Range | 1 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 18446744073709547520 | ||
Range | 1 .. 18446744073709547520 |
After this many write locks, permit some pending read lock requests to be processed in between.
Version Introduced | 5.6.4 | ||
Variable Name | metadata_locks_cache_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 1024 | ||
Range | 1 .. 1048576 |
The size of the metadata locks cache. The server uses this cache to avoid creation and destruction of synchronization objects. This is particularly helpful on systems where such operations are expensive, such as Windows XP. This variable was added in MySQL 5.6.4.
Version Introduced | 5.6.8 | ||
Variable Name | metadata_locks_hash_instances | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 8 | ||
Range | 1 .. 1024 |
The set of metadata locks can be partitioned into separate
hashes to permit connections accessing different objects to
use different locking hashes and reduce contention. The
metadata_locks_hash_instances
system variable specifies the number of hashes (default 8).
This variable was added in MySQL 5.6.8.
Command-Line Format | --min-examined-row-limit=# | ||
Option-File Format | min-examined-row-limit | ||
Variable Name | min_examined_row_limit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 18446744073709547520 |
Queries that examine fewer than this number of rows are not logged to the slow query log.
Command-Line Format | --myisam_data_pointer_size=# | ||
Option-File Format | myisam_data_pointer_size | ||
Option Sets Variable | Yes, myisam_data_pointer_size | ||
Variable Name | myisam_data_pointer_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 6 | ||
Range | 2 .. 7 |
The default pointer size in bytes, to be used by
CREATE TABLE
for
MyISAM
tables when no
MAX_ROWS
option is specified. This variable
cannot be less than 2 or larger than 7. The default value is
6. See Section C.5.2.12, “The table is full
”.
Command-Line Format | --myisam_max_sort_file_size=# | ||
Option-File Format | myisam_max_sort_file_size | ||
Option Sets Variable | Yes, myisam_max_sort_file_size | ||
Variable Name | myisam_max_sort_file_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 2147483648 |
The maximum size of the temporary file that MySQL is permitted
to use while re-creating a MyISAM
index
(during REPAIR TABLE
,
ALTER TABLE
, or
LOAD DATA
INFILE
). If the file size would be larger than this
value, the index is created using the key cache instead, which
is slower. The value is given in bytes.
The default value is 2GB. If MyISAM
index
files exceed this size and disk space is available, increasing
the value may help performance. The space must be available in
the file system containing the directory where the original
index file is located.
Command-Line Format | --myisam_mmap_size=# | ||
Option-File Format | myisam_mmap_size | ||
Option Sets Variable | Yes, myisam_mmap_size | ||
Variable Name | myisam_mmap_size | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 4294967295 | ||
Range | 7 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 18446744073709547520 | ||
Range | 7 .. 18446744073709547520 |
The maximum amount of memory to use for memory mapping
compressed MyISAM
files. If many
compressed MyISAM
tables are used, the
value can be decreased to reduce the likelihood of
memory-swapping problems.
Variable Name | myisam_recover_options | ||
Variable Scope | Global | ||
Dynamic Variable | No |
The value of the
--myisam-recover-options
option. See Section 5.1.3, “Server Command Options”.
Command-Line Format | --myisam_repair_threads=# | ||
Option-File Format | myisam_repair_threads | ||
Option Sets Variable | Yes, myisam_repair_threads | ||
Variable Name | myisam_repair_threads | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 1 | ||
Range | 1 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1 | ||
Range | 1 .. 18446744073709547520 |
If this value is greater than 1, MyISAM
table indexes are created in parallel (each index in its own
thread) during the Repair by sorting
process. The default value is 1.
Multi-threaded repair is still beta-quality code.
Command-Line Format | --myisam_sort_buffer_size=# | ||
Option-File Format | myisam_sort_buffer_size | ||
Option Sets Variable | Yes, myisam_sort_buffer_size | ||
Variable Name | myisam_sort_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 8388608 | ||
Range | 4 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 8388608 | ||
Range | 4 .. 18446744073709547520 |
The size of the buffer that is allocated when sorting
MyISAM
indexes during a
REPAIR TABLE
or when creating
indexes with CREATE INDEX
or
ALTER TABLE
.
The maximum permissible setting for
myisam_sort_buffer_size
is
4GB. Values larger than 4GB are permitted for 64-bit platforms
(except 64-bit Windows, for which large values are truncated
to 4GB with a warning).
Command-Line Format | --myisam_stats_method=name | ||
Option-File Format | myisam_stats_method | ||
Option Sets Variable | Yes, myisam_stats_method | ||
Variable Name | myisam_stats_method | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Valid Values |
|
How the server treats NULL
values when
collecting statistics about the distribution of index values
for MyISAM
tables. This variable has three
possible values, nulls_equal
,
nulls_unequal
, and
nulls_ignored
. For
nulls_equal
, all NULL
index values are considered equal and form a single value
group that has a size equal to the number of
NULL
values. For
nulls_unequal
, NULL
values are considered unequal, and each
NULL
forms a distinct value group of size
1. For nulls_ignored
,
NULL
values are ignored.
The method that is used for generating table statistics
influences how the optimizer chooses indexes for query
execution, as described in
Section 8.3.7, “InnoDB
and MyISAM
Index Statistics
Collection”.
Command-Line Format | --myisam_use_mmap | ||
Option-File Format | myisam_use_mmap | ||
Option Sets Variable | Yes, myisam_use_mmap | ||
Variable Name | myisam_use_mmap | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Use memory mapping for reading and writing
MyISAM
tables.
Variable Name | named_pipe | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Platform Specific | windows | ||
Permitted Values | |||
Type (windows) | boolean | ||
Default | OFF |
(Windows only.) Indicates whether the server supports connections over named pipes.
Command-Line Format | --net_buffer_length=# | ||
Option-File Format | net_buffer_length | ||
Option Sets Variable | Yes, net_buffer_length | ||
Variable Name | net_buffer_length | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 16384 | ||
Range | 1024 .. 1048576 |
Each client thread is associated with a connection buffer and
result buffer. Both begin with a size given by
net_buffer_length
but are
dynamically enlarged up to
max_allowed_packet
bytes as
needed. The result buffer shrinks to
net_buffer_length
after each
SQL statement.
This variable should not normally be changed, but if you have
very little memory, you can set it to the expected length of
statements sent by clients. If statements exceed this length,
the connection buffer is automatically enlarged. The maximum
value to which
net_buffer_length
can be set
is 1MB.
The session value of this variable is read only.
Command-Line Format | --net_read_timeout=# | ||
Option-File Format | net_read_timeout | ||
Option Sets Variable | Yes, net_read_timeout | ||
Variable Name | net_read_timeout | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 30 | ||
Min Value | 1 |
The number of seconds to wait for more data from a connection
before aborting the read. When the server is reading from the
client, net_read_timeout
is
the timeout value controlling when to abort. When the server
is writing to the client,
net_write_timeout
is the
timeout value controlling when to abort. See also
slave_net_timeout
.
Command-Line Format | --net_retry_count=# | ||
Option-File Format | net_retry_count | ||
Option Sets Variable | Yes, net_retry_count | ||
Variable Name | net_retry_count | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 10 | ||
Range | 1 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 10 | ||
Range | 1 .. 18446744073709547520 |
If a read or write on a communication port is interrupted, retry this many times before giving up. This value should be set quite high on FreeBSD because internal interrupts are sent to all threads.
Command-Line Format | --net_write_timeout=# | ||
Option-File Format | net_write_timeout | ||
Option Sets Variable | Yes, net_write_timeout | ||
Variable Name | net_write_timeout | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 60 | ||
Min Value | 1 |
The number of seconds to wait for a block to be written to a
connection before aborting the write. See also
net_read_timeout
.
Command-Line Format | --new | ||
-n | |||
Option-File Format | new | ||
Option Sets Variable | Yes, new | ||
Variable Name | new | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Disabled by | skip-new | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
This variable was used in MySQL 4.0 to turn on some 4.1
behaviors, and is retained for backward compatibility. In
MySQL 5.6, its value is always
OFF
.
Command-Line Format | --old | ||
Option-File Format | old | ||
Variable Name | old | ||
Variable Scope | Global | ||
Dynamic Variable | No |
old
is a compatibility
variable. It is disabled by default, but can be enabled at
startup to revert the server to behaviors present in older
versions.
Currently, when old
is
enabled, it changes the default scope of index hints to that
used prior to MySQL 5.1.17. That is, index hints with no
FOR
clause apply only to how indexes are
used for row retrieval and not to resolution of ORDER
BY
or GROUP BY
clauses. (See
Section 13.2.9.3, “Index Hint Syntax”.) Take care about enabling this
in a replication setup. With statement-based binary logging,
having different modes for the master and slaves might lead to
replication errors.
Command-Line Format | --old-alter-table | ||
Option-File Format | old-alter-table | ||
Option Sets Variable | Yes, old_alter_table | ||
Variable Name | old_alter_table | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
When this variable is enabled, the server does not use the
optimized method of processing an ALTER
TABLE
operation. It reverts to using a temporary
table, copying over the data, and then renaming the temporary
table to the original, as used by MySQL 5.0 and earlier. For
more information on the operation of
ALTER TABLE
, see
Section 13.1.6, “ALTER TABLE
Syntax”.
Variable Name | old_passwords | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Type | boolean | ||
Default | 0 | ||
Permitted Values (>= 5.6.6) | |||
Type | enumeration | ||
Default | 0 | ||
Valid Values |
|
This variable determines the type of password hashing
performed by the PASSWORD()
function and statements such as CREATE
USER
and GRANT
.
The following table shows the permitted values of
old_passwords
, as well as the
type of password hashing each value produces, and the plugins
that use each hashing type. These values are permitted as of
MySQL 5.6.6. Before 5.6.6, the value can be 0 (or
OFF
), or 1 (or ON
).
Value | Password Hashing Format | Intended Use |
---|---|---|
0 | MySQL 4.1 native hashing | Accounts that authenticate with the
mysql_native_password plugin |
1 | Pre-4.1 (“old”) native hashing | Accounts that authenticate with the
mysql_old_password plugin |
2 | SHA-256 hashing | Accounts that authenticate with the sha256_password
plugin |
If old_passwords=1
,
PASSWORD('
returns the same value as
str
')OLD_PASSWORD('
.
str
')
For information about authentication plugins and hashing
formats, see Section 6.3.6, “Pluggable Authentication”, and
Section 6.1.2.4, “Password Hashing in MySQL”. If you set If
old_passwords=2
, follow the instructions
for using the sha256_password
plugin at
Section 6.3.6.2, “The SHA-256 Authentication Plugin”.
Command-Line Format | --open-files-limit=# | ||
Option-File Format | open-files-limit | ||
Option Sets Variable | Yes, open_files_limit | ||
Variable Name | open_files_limit | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (<= 5.6.7) | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 65535 | ||
Permitted Values (>= 5.6.8) | |||
Type | numeric | ||
Default | -1 (autosized) | ||
Range | 0 .. 65535 |
The number of files that the operating system permits mysqld to open. The value of this variable at runtime is the real value permitted by the system and might be different from the value you specify at server startup. The value is 0 on systems where MySQL cannot change the number of open files.
The effective
open_files_limit
value is
based on the value specified at system startup (if any) and
the values of max_connections
and table_open_cache
, using
these formulas:
1) 10 + max_connections + (table_open_cache * 2) 2) max_connections * 5 3) open_files_limit value specified at startup, 5000 if none
The server attempts to obtain the number of file descriptors using the maximum of those three values. If that many descriptors cannot be obtained, the server attempts to obtain as many as the system will permit.
Version Introduced | 5.6.1 | ||
Version Removed | 5.6.3 | ||
Command-Line Format | --optimizer_join_cache_level=# | ||
Option-File Format | optimizer_join_cache_level | ||
Option Sets Variable | Yes, optimizer_join_cache_level | ||
Variable Name | optimizer_join_cache_level | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 4 | ||
Range | 0 .. 4 |
Before MySQL 5.6.3, this variable is used for join buffer
management. It controls how join buffers are used for join
operations. As of MySQL 5.6.3, it is removed and the
optimizer_switch
variable is
used instead. See Section 8.13.11, “Block Nested-Loop and Batched Key Access Joins”.
The following table shows the permissible
optimizer_join_cache_level
values.
Option | Description |
---|---|
0 | No join buffer is used for any join operation. This setting can be useful for assessing baseline join performance in comparison to performance with nonzero values that enable use of join buffering. |
1 | This is the default value. Join buffers are employed only for inner joins that are executed by the original Block Nested-Loop (BNL) join algorithm. When this algorithm is applied, rows of the inner table are accessed through a table scan, a plain index scan, or a range index scan. |
2 | The server employs an incremental join buffer for a join operation if its first operand is produced by a join operation that uses a join buffer itself. |
3 | The BNL algorithm is used for outer join operations with one inner table and for inner joins. |
4 | The BNL algorithm uses incremental buffers for inner tables. In this case, the BNL algorithm can be used for nested outer joins (outer joins with several inner tables). Such an operation can be executed only if incremental join buffers are used to join all inner tables but the first one. |
Command-Line Format | --optimizer_prune_level[=#] | ||
Option-File Format | optimizer_prune_level | ||
Option Sets Variable | Yes, optimizer_prune_level | ||
Variable Name | optimizer_prune_level | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 1 |
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.
Command-Line Format | --optimizer_search_depth[=#] | ||
Option-File Format | optimizer_search_depth | ||
Option Sets Variable | Yes, optimizer_search_depth | ||
Variable Name | optimizer_search_depth | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (>= 5.6) | |||
Type | numeric | ||
Default | 62 | ||
Range | 0 .. 62 |
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.
Command-Line Format | --optimizer_switch=value | ||
Option-File Format | optimizer_switch | ||
optimizer_switch | |||
optimizer_switch | |||
Option Sets Variable | Yes, optimizer_switch | ||
Variable Name | optimizer_switch | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (>= 5.6.1, <= 5.6.2) | |||
Type | set | ||
Valid Values |
| ||
Permitted Values (>= 5.6.3) | |||
Type | set | ||
Valid Values |
|
The optimizer_switch
system
variable enables control over optimizer behavior. The value of
this variable is a set of flags, each of which has a value of
on
or off
to indicate
whether the corresponding optimizer behavior is enabled or
disabled. This variable has global and session values and can
be changed at runtime. The global default can be set at server
startup.
To see the current set of optimizer flags, select the variable value:
mysql> SELECT @@optimizer_switch\G
*************************** 1. row ***************************
@@optimizer_switch: index_merge=on,index_merge_union=on,
index_merge_sort_union=on,
index_merge_intersection=on,
engine_condition_pushdown=on,
index_condition_pushdown=on,
mrr=on,mrr_cost_based=on,
block_nested_loop=on,batched_key_access=off,
materialization=on,semijoin=on,
loosescan=on,firstmatch=on
For more information about the syntax of this variable and the optimizer behaviors that it controls, see Section 8.8.5.2, “Controlling Switchable Optimizations”.
Version Introduced | 5.6.3 | ||
Variable Name | optimizer_trace | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
This variable controls optimizer tracing. For details, see MySQL Internals: Tracing the Optimizer. This variable was added in MySQL 5.6.3.
Version Introduced | 5.6.3 | ||
Variable Name | optimizer_trace_features | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
This variable enables or disables selected optimizer tracing features. For details, see MySQL Internals: Tracing the Optimizer. This variable was added in MySQL 5.6.3.
Version Introduced | 5.6.3 | ||
Variable Name | optimizer_trace_limit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 1 |
The maximum number of optimizer traces to display. For details, see MySQL Internals: Tracing the Optimizer. This variable was added in MySQL 5.6.3.
Version Introduced | 5.6.3 | ||
Variable Name | optimizer_trace_max_mem_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 16384 |
The maximum cumulative size of stored optimizer traces. For details, see MySQL Internals: Tracing the Optimizer. This variable was added in MySQL 5.6.3.
Version Introduced | 5.6.3 | ||
Variable Name | optimizer_trace_offset | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | -1 |
The offset of optimizer traces to display. For details, see MySQL Internals: Tracing the Optimizer. This variable was added in MySQL 5.6.3.
performance_schema_
xxx
Performance Schema system variables are listed in Section 20.11, “Performance Schema System Variables”.
Command-Line Format | --pid-file=file_name | ||
Option-File Format | pid-file=file_name | ||
Option Sets Variable | Yes, pid_file | ||
Variable Name | pid_file | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The path name of the process ID (PID) file. This variable can
be set with the --pid-file
option.
Command-Line Format | --plugin_dir=path | ||
Option-File Format | plugin_dir | ||
Option Sets Variable | Yes, plugin_dir | ||
Variable Name | plugin_dir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name | ||
Default | BASEDIR/lib/plugin |
The path name of the plugin directory.
If the plugin directory is writable by the server, it may be
possible for a user to write executable code to a file in the
directory using SELECT
... INTO DUMPFILE
. This can be prevented by making
plugin_dir
read only to the
server or by setting
--secure-file-priv
to a
directory where SELECT
writes
can be made safely.
Command-Line Format | --port=# | ||
-P | |||
Option-File Format | port | ||
Option Sets Variable | Yes, port | ||
Variable Name | port | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 3306 |
The number of the port on which the server listens for TCP/IP
connections. This variable can be set with the
--port
option.
Command-Line Format | --preload_buffer_size=# | ||
Option-File Format | preload_buffer_size | ||
Option Sets Variable | Yes, preload_buffer_size | ||
Variable Name | preload_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 32768 | ||
Range | 1024 .. 1073741824 |
The size of the buffer that is allocated when preloading indexes.
If set to 0 or OFF
(the default), statement
profiling is disabled. If set to 1 or ON
,
statement profiling is enabled and the
SHOW PROFILE
and
SHOW PROFILES
statements
provide access to profiling information. See
Section 13.7.5.32, “SHOW PROFILES
Syntax”.
This variable is deprecated in MySQL 5.6.8 and will be removed in a future MySQL release.
The number of statements for which to maintain profiling
information if profiling
is
enabled. The default value is 15. The maximum value is 100.
Setting the value to 0 effectively disables profiling. See
Section 13.7.5.32, “SHOW PROFILES
Syntax”.
This variable is deprecated in MySQL 5.6.8 and will be removed in a future MySQL release.
Variable Name | protocol_version | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric |
The version of the client/server protocol used by the MySQL server.
Variable Name | proxy_user | ||
Variable Scope | Session | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
If the current client is a proxy for another user, this
variable is the proxy user account name. Otherwise, this
variable is NULL
. See
Section 6.3.7, “Proxy Users”.
Variable Name | pseudo_thread_id | ||
Variable Scope | Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric |
This variable is for internal server use.
Command-Line Format | --query_alloc_block_size=# | ||
Option-File Format | query_alloc_block_size | ||
Option Sets Variable | Yes, query_alloc_block_size | ||
Variable Name | query_alloc_block_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 8192 | ||
Range | 1024 .. 4294967295 | ||
Block Size | 1024 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 8192 | ||
Range | 1024 .. 18446744073709547520 | ||
Block Size | 1024 |
The allocation size of memory blocks that are allocated for objects created during statement parsing and execution. If you have problems with memory fragmentation, it might help to increase this parameter.
Command-Line Format | --query_cache_limit=# | ||
Option-File Format | query_cache_limit | ||
Option Sets Variable | Yes, query_cache_limit | ||
Variable Name | query_cache_limit | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 1048576 | ||
Range | 0 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1048576 | ||
Range | 0 .. 18446744073709547520 |
Do not cache results that are larger than this number of bytes. The default value is 1MB.
Command-Line Format | --query_cache_min_res_unit=# | ||
Option-File Format | query_cache_min_res_unit | ||
Option Sets Variable | Yes, query_cache_min_res_unit | ||
Variable Name | query_cache_min_res_unit | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 4096 | ||
Range | 512 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 4096 | ||
Range | 512 .. 18446744073709547520 |
The minimum size (in bytes) for blocks allocated by the query cache. The default value is 4096 (4KB). Tuning information for this variable is given in Section 8.9.3.3, “Query Cache Configuration”.
Command-Line Format | --query_cache_size=# | ||
Option-File Format | query_cache_size | ||
Option Sets Variable | Yes, query_cache_size | ||
Variable Name | query_cache_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.7) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 18446744073709547520 | ||
Permitted Values (<= 5.6.7) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 | ||
Permitted Values (>= 5.6.8) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 1048576 | ||
Range | 0 .. 18446744073709547520 | ||
Permitted Values (>= 5.6.8) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 1048576 | ||
Range | 0 .. 4294967295 |
The amount of memory allocated for caching query results. By
default, the query cache is disabled. This is achieved using a
default value of 1M, with a default for
query_cache_type
of 0. (Before MySQL 5.6.8,
the default size is 0, with a default
query_cache_type
of` 1. To reduce overhead
significantly, you should also start the server with
query_cache_type=0
if you
will not be using the query cache.)
The permissible 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 if
query_cache_type
is set to 0.
See Section 8.9.3.3, “Query Cache Configuration”, for more
information.
The query cache needs a minimum size of about 40KB to allocate
its structures. (The exact size depends on system
architecture.) If you set the value of
query_cache_size
too small, a
warning will occur, as described in
Section 8.9.3.3, “Query Cache Configuration”.
Command-Line Format | --query_cache_type=# | ||
Option-File Format | query_cache_type | ||
Option Sets Variable | Yes, query_cache_type | ||
Variable Name | query_cache_type | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.7) | |||
Type | enumeration | ||
Default | 1 | ||
Valid Values |
| ||
Permitted Values (>= 5.6.8) | |||
Type | enumeration | ||
Default | 0 | ||
Valid Values |
|
Set the query cache type. Setting the
GLOBAL
value sets the type for all clients
that connect thereafter. Individual clients can set the
SESSION
value to affect their own use of
the query cache. Possible values are shown in the following
table.
Option | Description |
---|---|
0 or OFF | Do not cache results in or retrieve results from the query cache. Note
that this does not deallocate the query cache buffer.
To do that, you should set
query_cache_size to
0. |
1 or ON | Cache all cacheable query results except for those that begin with
SELECT SQL_NO_CACHE . |
2 or DEMAND | Cache results only for cacheable queries that begin with SELECT
SQL_CACHE . |
This variable defaults to ON
.
If the server is started with
query_cache_type
set to 0, it does not
acquire the query cache mutex at all, which means that the
query cache cannot be enabled at runtime and there is reduced
overhead in query execution.
Command-Line Format | --query_cache_wlock_invalidate | ||
Option-File Format | query_cache_wlock_invalidate | ||
Option Sets Variable | Yes, query_cache_wlock_invalidate | ||
Variable Name | query_cache_wlock_invalidate | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | FALSE |
Normally, when one client acquires a WRITE
lock on a MyISAM
table, other clients are
not blocked from issuing statements that read from the table
if the query results are present in the query cache. Setting
this variable to 1 causes acquisition of a
WRITE
lock for a table to invalidate any
queries in the query cache that refer to the table. This
forces other clients that attempt to access the table to wait
while the lock is in effect.
Command-Line Format | --query_prealloc_size=# | ||
Option-File Format | query_prealloc_size | ||
Option Sets Variable | Yes, query_prealloc_size | ||
Variable Name | query_prealloc_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 8192 | ||
Range | 8192 .. 4294967295 | ||
Block Size | 1024 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 8192 | ||
Range | 8192 .. 18446744073709547520 | ||
Block Size | 1024 |
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.
The rand_seed1
and
rand_seed2
variables exist as
session variables only, and can be set but not read. The
variables—but not their values—are shown in the
output of SHOW VARIABLES
.
The purpose of these variables is to support replication of
the RAND()
function. For
statements that invoke RAND()
,
the master passes two values to the slave, where they are used
to seed the random number generator. The slave uses these
values to set the session variables
rand_seed1
and
rand_seed2
so that
RAND()
on the slave generates
the same value as on the master.
See the description for
rand_seed1
.
Command-Line Format | --range_alloc_block_size=# | ||
Option-File Format | range_alloc_block_size | ||
Option Sets Variable | Yes, range_alloc_block_size | ||
Variable Name | range_alloc_block_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 4096 | ||
Range | 4096 .. 4294967295 | ||
Block Size | 1024 |
The size of blocks that are allocated when doing range optimization.
Command-Line Format | --read_buffer_size=# | ||
Option-File Format | read_buffer_size | ||
Option Sets Variable | Yes, read_buffer_size | ||
Variable Name | read_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 131072 | ||
Range | 8200 .. 2147479552 |
Each thread that does a sequential scan for a
MyISAM
table allocates a buffer of this
size (in bytes) for each table it scans. If you do many
sequential scans, you might want to increase this value, which
defaults to 131072. The value of this variable should be a
multiple of 4KB. If it is set to a value that is not a
multiple of 4KB, its value will be rounded down to the nearest
multiple of 4KB.
The maximum permissible setting for
read_buffer_size
is 2GB.
For more information about memory use during different operations, see Section 8.11.4.1, “How MySQL Uses Memory”.
Command-Line Format | --read-only | ||
Option-File Format | read_only | ||
Option Sets Variable | Yes, read_only | ||
Variable Name | read_only | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | false |
This variable is off by default. When it is enabled, the
server permits no updates except from users that have the
SUPER
privilege or (on a slave
server) from updates performed by slave threads. In
replication setups, it can be useful to enable
read_only
on slave servers to
ensure that slaves accept updates only from the master server
and not from clients.
read_only
does not apply to
TEMPORARY
tables, nor does it prevent the
server from inserting rows into the log tables (see
Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”). This variable does not
prevent the use of ANALYZE
TABLE
or OPTIMIZE
TABLE
statements because its purpose is to prevent
changes to table structure or contents. Analysis and
optimization do not qualify as such changes. This means, for
example, that consistency checks on read-only slaves can be
performed with mysqlcheck --all-databases
--analyze.
read_only
exists only as a
GLOBAL
variable, so changes to its value
require the SUPER
privilege.
Changes to read_only
on a
master server are not replicated to slave servers. The value
can be set on a slave server independent of the setting on the
master.
In MySQL 5.6, enabling
read_only
prevents the use of the
SET PASSWORD
statement by any
user not having the SUPER
privilege. This is not necessarily the case for all MySQL
release series. When replicating from one MySQL release
series to another (for example, from a MySQL 5.0 master to a
MySQL 5.1 or later slave), you should check the
documentation for the versions running on both master and
slave to determine whether the behavior of
read_only
in this regard is or is not the
same, and, if it is different, whether this has an impact on
your applications.
The following conditions apply:
If you attempt to enable
read_only
while you have
any explicit locks (acquired with
LOCK TABLES
) or have a
pending transaction, an error occurs.
If you attempt to enable
read_only
while other
clients hold explicit table locks or have pending
transactions, the attempt blocks until the locks are
released and the transactions end. While the attempt to
enable read_only
is
pending, requests by other clients for table locks or to
begin transactions also block until
read_only
has been set.
read_only
can be enabled
while you hold a global read lock (acquired with
FLUSH TABLES WITH
READ LOCK
) because that does not involve table
locks.
In MySQL 5.6, attempts to set
read_only
block for active
transactions that hold metadata locks until those transactions
end.
Command-Line Format | --read_rnd_buffer_size=# | ||
Option-File Format | read_rnd_buffer_size | ||
Option Sets Variable | Yes, read_rnd_buffer_size | ||
Variable Name | read_rnd_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 262144 | ||
Range | 8200 .. 4294967295 |
When reading rows from a MyISAM
table in
sorted order following a key-sorting operation, the rows are
read through this buffer to avoid disk seeks. See
Section 8.13.12, “ORDER BY
Optimization”. Setting the variable
to a large value can improve ORDER BY
performance by a lot. However, this is a buffer allocated for
each client, so you should not set the global variable to a
large value. Instead, change the session variable only from
within those clients that need to run large queries.
The maximum permissible setting for
read_rnd_buffer_size
is 2GB.
For more information about memory use during different operations, see Section 8.11.4.1, “How MySQL Uses Memory”.
Command-Line Format | --relay_log_purge | ||
Option-File Format | relay_log_purge | ||
Option Sets Variable | Yes, relay_log_purge | ||
Variable Name | relay_log_purge | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
Disables or enables automatic purging of relay log files as
soon as they are not needed any more. The default value is 1
(ON
).
Command-Line Format | --relay_log_space_limit=# | ||
Option-File Format | relay_log_space_limit | ||
Option Sets Variable | Yes, relay_log_space_limit | ||
Variable Name | relay_log_space_limit | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 18446744073709547520 |
The maximum amount of space to use for all relay logs.
Command-Line Format | --report-host=host_name | ||
Option-File Format | report-host | ||
Option Sets Variable | Yes, report_host | ||
Variable Name | report-host | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The value of the --report-host
option.
Command-Line Format | --report-password=name | ||
Option-File Format | report-password | ||
Option Sets Variable | Yes, report_password | ||
Variable Name | report-password | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The value of the
--report-password
option. Not
the same as the password used for the MySQL replication user
account.
Command-Line Format | --report-port=# | ||
Option-File Format | report-port | ||
Option Sets Variable | Yes, report_port | ||
Variable Name | report-port | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values (>= 5.6.5) | |||
Type | numeric | ||
Default | [slave_port] |
The value of the --report-port
option.
Command-Line Format | --report-user=name | ||
Option-File Format | report-user | ||
Option Sets Variable | Yes, report_user | ||
Variable Name | report-user | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The value of the --report-user
option. Not the same as the name for the MySQL replication
user account.
Variable Name | rpl_semi_sync_master_enabled | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Controls whether semisynchronous replication is enabled on the
master. To enable or disable the plugin, set this variable to
ON
or OFF
(or 1 or 0),
respectively. The default is OFF
.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Variable Name | rpl_semi_sync_master_timeout | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 10000 |
A value in milliseconds that controls how long the master waits on a commit for acknowledgment from a slave before timing out and reverting to asynchronous replication. The default value is 10000 (10 seconds).
This variable is available only if the master-side semisynchronous replication plugin is installed.
rpl_semi_sync_master_trace_level
Variable Name | rpl_semi_sync_master_trace_level | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 32 |
The semisynchronous replication debug trace level on the master. Currently, four levels are defined:
1 = general level (for example, time function failures)
16 = detail level (more verbose information)
32 = net wait level (more information about network waits)
64 = function level (information about function entry and exit)
This variable is available only if the master-side semisynchronous replication plugin is installed.
rpl_semi_sync_master_wait_no_slave
Variable Name | rpl_semi_sync_master_wait_no_slave | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | ON |
With semisynchronous replication, for each transaction, the master waits until timeout for acknowledgment of receipt from some semisynchronous slave. If no response occurs during this period, the master reverts to normal replication. This variable controls whether the master waits for the timeout to expire before reverting to normal replication even if the slave count drops to zero during the timeout period.
If the value is ON
(the default), it is
permissible for the slave count to drop to zero during the
timeout period (for example, if slaves disconnect). The master
still waits for the timeout, so as long as some slave
reconnects and acknowledges the transaction within the timeout
interval, semisynchronous replication continues.
If the value is OFF
, the master reverts to
normal replication if the slave count drops to zero during the
timeout period.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Variable Name | rpl_semi_sync_slave_enabled | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Controls whether semisynchronous replication is enabled on the
slave. To enable or disable the plugin, set this variable to
ON
or OFF
(or 1 or 0),
respectively. The default is OFF
.
This variable is available only if the slave-side semisynchronous replication plugin is installed.
rpl_semi_sync_slave_trace_level
Variable Name | rpl_semi_sync_slave_trace_level | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 32 |
The semisynchronous replication debug trace level on the
slave. See
rpl_semi_sync_master_trace_level
for the permissible values.
This variable is available only if the slave-side semisynchronous replication plugin is installed.
Command-Line Format | --secure-auth | ||
Option-File Format | secure-auth | ||
Option Sets Variable | Yes, secure_auth | ||
Variable Name | secure_auth | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.4) | |||
Type | boolean | ||
Default | OFF | ||
Permitted Values (>= 5.6.5) | |||
Type | boolean | ||
Default | ON |
If this variable is enabled, the server blocks connections by clients that attempt to use accounts that have passwords stored in the old (pre-4.1) format.
Enable this variable to prevent all use of passwords employing the old format (and hence insecure communication over the network). Before MySQL 5.6.5, this variable is disabled by default. As of MySQL 5.6.5, it is enabled by default.
Server startup fails with an error if this variable is enabled
and the privilege tables are in pre-4.1 format. See
Section C.5.2.4, “Client does not support authentication protocol
”.
Command-Line Format | --secure-file-priv=path | ||
Option-File Format | secure-file-priv=path | ||
Option Sets Variable | Yes, secure_file_priv | ||
Variable Name | secure-file-priv | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
By default, this variable is empty. If set to the name of a
directory, it limits the effect of the
LOAD_FILE()
function and the
LOAD DATA
and
SELECT ... INTO
OUTFILE
statements to work only with files in that
directory.
Command-Line Format | --server-id=# | ||
Option-File Format | server-id | ||
Option Sets Variable | Yes, server_id | ||
Variable Name | server_id | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 4294967295 |
The server ID, used in replication to give each master and
slave a unique identity. This variable is set by the
--server-id
option. For each
server participating in replication, you should pick a
positive integer in the range from 1 to
232 – 1 to act as that
server's ID.
sha256_password_private_key_path
Version Introduced | 5.6.6 | ||
Variable Name | sha256_password_private_key_path | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name | ||
Default | private_key.pem |
The path name of the RSA private key file for the
sha256_password
authentication plugin. If
the file is named as a relative path, it is interpreted
relative to the server data directory. The file must be in PEM
format. Because this file stores a private key, its access
mode should be restricted so that only the MySQL server can
read it.
For information about sha256_password
,
including instructions for creating the RSA key files, see
Section 6.3.6.2, “The SHA-256 Authentication Plugin”.
This variable is available only if MySQL was built using OpenSSL. It was added in MySQL 5.6.6.
sha256_password_public_key_path
Version Introduced | 5.6.6 | ||
Variable Name | sha256_password_public_key_path | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name | ||
Default | public_key.pem |
The path name of the RSA public key file for the
sha256_password
authentication plugin. If
the file is named as a relative path, it is interpreted
relative to the server data directory. The file must be in PEM
format. Because this file stores a public key, copies can be
freely distributed to client users. (Clients that explicitly
specify a public key when connecting to the server using RSA
password encryption must use the same public key as that used
by the server.)
For information about sha256_password
,
including instructions for creating the RSA key files and how
clients specify the RSA public key, see
Section 6.3.6.2, “The SHA-256 Authentication Plugin”.
This variable is available only if MySQL was built using OpenSSL. It was added in MySQL 5.6.6.
Variable Name | shared_memory | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Platform Specific | windows |
(Windows only.) Whether the server permits shared-memory connections.
Variable Name | shared_memory_base_name | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Platform Specific | windows |
(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. This affects only
MyISAM
table access.
This variable is set from the value of the
--skip-name-resolve
option. If
it is ON
, mysqld
resolves host names when checking client connections. If
OFF
, mysqld uses only IP
numbers and all Host
column values in the
grant tables must be IP addresses or
localhost
. See
Section 8.11.5.2, “DNS Lookup Optimization and the Host Cache”.
This is ON
if the server permits only local
(non-TCP/IP) connections. On Unix, local connections use a
Unix socket file. On Windows, local connections use a named
pipe or shared memory. This variable can be set to
ON
with the
--skip-networking
option.
This prevents people from using the SHOW
DATABASES
statement if they do not have the
SHOW DATABASES
privilege. This
can improve security if you have concerns about users being
able to see databases belonging to other users. Its effect
depends on the SHOW DATABASES
privilege: If the variable value is ON
, the
SHOW DATABASES
statement is
permitted only to users who have the SHOW
DATABASES
privilege, and the statement displays all
database names. If the value is OFF
,
SHOW DATABASES
is permitted to
all users, but displays the names of only those databases for
which the user has the SHOW
DATABASES
or other privilege.
Command-Line Format | --slow_launch_time=# | ||
Option-File Format | slow_launch_time | ||
Option Sets Variable | Yes, slow_launch_time | ||
Variable Name | slow_launch_time | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 2 |
If creating a thread takes longer than this many seconds, the
server increments the
Slow_launch_threads
status
variable.
Command-Line Format | --slow-query-log | ||
Option-File Format | slow-query-log | ||
Option Sets Variable | Yes, slow_query_log | ||
Variable Name | slow_query_log | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
Whether the slow query log is enabled. The value can be 0 (or
OFF
) to disable the log or 1 (or
ON
) to enable the log. The default value
depends on whether the
--slow_query_log
option is
given. The destination for log output is controlled by the
log_output
system variable;
if that value is NONE
, no log entries are
written even if the log is enabled.
“Slow” is determined by the value of the
long_query_time
variable. See
Section 5.2.5, “The Slow Query Log”.
Command-Line Format | --slow-query-log-file=file_name | ||
Option-File Format | slow_query_log_file | ||
Option Sets Variable | Yes, slow_query_log_file | ||
Variable Name | slow_query_log_file | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | file name |
The name of the slow query log file. The default value is
,
but the initial value can be changed with the
host_name
-slow.log--slow_query_log_file
option.
Command-Line Format | --socket=name | ||
Option-File Format | socket | ||
Option Sets Variable | Yes, socket | ||
Variable Name | socket | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name | ||
Default | /tmp/mysql.sock |
On Unix platforms, this variable is the name of the socket
file that is used for local client connections. The default is
/tmp/mysql.sock
. (For some distribution
formats, the directory might be different, such as
/var/lib/mysql
for RPMs.)
On Windows, this variable is the name of the named pipe that
is used for local client connections. The default value is
MySQL
(not case sensitive).
Command-Line Format | --sort_buffer_size=# | ||
Option-File Format | sort_buffer_size | ||
Option Sets Variable | Yes, sort_buffer_size | ||
Variable Name | sort_buffer_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.3) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 2097144 | ||
Range | 32768 .. 18446744073709547520 | ||
Permitted Values (<= 5.6.3) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 2097144 | ||
Range | 32768 .. 4294967295 | ||
Permitted Values (>= 5.6.4) | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 262144 | ||
Range | 32768 .. 18446744073709547520 | ||
Permitted Values (>= 5.6.4) | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 262144 | ||
Range | 32768 .. 4294967295 |
Each session that needs to do a sort allocates a buffer of
this size. sort_buffer_size
is not specific to any storage engine and applies in a general
manner for optimization. See
Section 8.13.12, “ORDER BY
Optimization”, for example.
If you see many
Sort_merge_passes
per second
in SHOW GLOBAL
STATUS
output, you can consider increasing the
sort_buffer_size
value to
speed up ORDER BY
or GROUP
BY
operations that cannot be improved with query
optimization or improved indexing.
As of MySQL 5.6.4, the optimiser tries to work out how much space is needed but can allocate more, up to the limit. Before MySQL 5.6.4, the optimizer allocates the entire buffer even if it is not all needed. In either case, setting it larger than required globally will slow down most queries that sort. It is best to increase it as a session setting, and only for the sessions that need a larger size. On Linux, there are thresholds of 256KB and 2MB where larger values may significantly slow down memory allocation, so you should consider staying below one of those values. Experiment to find the best value for your workload. See Section C.5.4.4, “Where MySQL Stores Temporary Files”.
The maximum permissible setting for
sort_buffer_size
is 4GB.
Values larger than 4GB are permitted for 64-bit platforms
(except 64-bit Windows, for which large values are truncated
to 4GB with a warning).
Variable Name | sql_auto_is_null | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 0 |
If this variable is set to 1, then after a statement that
successfully inserts an automatically generated
AUTO_INCREMENT
value, you can find that
value by issuing a statement of the following form:
SELECT * FROMtbl_name
WHEREauto_col
IS NULL
If the statement returns a row, the value returned is the same
as if you invoked the
LAST_INSERT_ID()
function. For
details, including the return value after a multiple-row
insert, see Section 12.14, “Information Functions”. If no
AUTO_INCREMENT
value was successfully
inserted, the SELECT
statement
returns no row.
The behavior of retrieving an
AUTO_INCREMENT
value by using an
IS NULL
comparison is used by
some ODBC programs, such as Access. See
Section 21.1.7.1.1, “Obtaining Auto-Increment Values”.
This behavior can be disabled by setting
sql_auto_is_null
to 0.
The default value of
sql_auto_is_null
is 0 in
MySQL 5.6.
Variable Name | sql_big_selects | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 1 |
If set to 0, MySQL aborts
SELECT
statements that are
likely to take a very long time to execute (that is,
statements for which the optimizer estimates that the number
of examined rows exceeds the value of
max_join_size
). This is
useful when an inadvisable WHERE
statement
has been issued. The default value for a new connection is 1,
which permits all SELECT
statements.
If you set the max_join_size
system variable to a value other than
DEFAULT
,
sql_big_selects
is set to 0.
Variable Name | sql_buffer_result | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 0 |
If set to 1,
sql_buffer_result
forces
results from SELECT
statements
to be put into temporary tables. This helps MySQL free the
table locks early and can be beneficial in cases where it
takes a long time to send results to the client. The default
value is 0.
Variable Name | sql_log_bin | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean |
This variable controls whether logging to the binary log is
done. The default value is 1 (do logging). To change logging
for the current session, change the session value of this
variable. The session user must have the
SUPER
privilege to set this
variable.
In MySQL 5.6, it is not possible to set
@@session.sql_log_bin
within a transaction
or subquery. (Bug #53437)
Variable Name | sql_log_off | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 0 |
This variable controls whether logging to the general query
log is done. The default value is 0 (do logging). To change
logging for the current session, change the session value of
this variable. The session user must have the
SUPER
privilege to set this
option. The default value is 0.
Command-Line Format | --sql-mode=name | ||
Option-File Format | sql-mode | ||
Option Sets Variable | Yes, sql_mode | ||
Variable Name | sql_mode | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.5) | |||
Type | set | ||
Default | '' | ||
Valid Values |
| ||
Permitted Values (>= 5.6.6) | |||
Type | set | ||
Default | NO_ENGINE_SUBSTITUTION | ||
Valid Values |
|
The current server SQL mode, which can be set dynamically. The
default as of MySQL 5.6.6 is
NO_ENGINE_SUBSTITUTION
; previously it was
an empty string. See Section 5.1.7, “Server SQL Modes”.
If set to 1 (the default), warnings of Note
level increment warning_count
and the
server records them. If set to 0, Note
warnings do not increment
warning_count
and the server
does not record them. mysqldump includes
output to set this variable to 0 so that reloading the dump
file does not produce warnings for events that do not affect
the integrity of the reload operation.
If set to 1 (the default), the server quotes identifiers for
SHOW CREATE TABLE
and
SHOW CREATE DATABASE
statements. If set to 0, quoting is disabled. This option is
enabled by default so that replication works for identifiers
that require quoting. See Section 13.7.5.12, “SHOW CREATE TABLE
Syntax”,
and Section 13.7.5.8, “SHOW CREATE DATABASE
Syntax”.
If set to 1, MySQL aborts
UPDATE
or
DELETE
statements that do not
use a key in the WHERE
clause or a
LIMIT
clause. This makes it possible to
catch UPDATE
or
DELETE
statements where keys
are not used properly and that would probably change or delete
a large number of rows. The default value is 0.
Variable Name | sql_select_limit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric |
The maximum number of rows to return from
SELECT
statements. The default
value for a new connection is the maximum number of rows that
the server permits per table. Typical default values are
(232)–1 or
(264)–1. If you have changed
the limit, the default value can be restored by assigning a
value of DEFAULT
.
If a SELECT
has a
LIMIT
clause, the LIMIT
takes precedence over the value of
sql_select_limit
.
sql_select_limit
does not
apply to SELECT
statements
executed within stored routines. It also does not apply to
SELECT
statements that do not
produce a result set to be returned to the client. These
include SELECT
statements in
subqueries,
CREATE TABLE ...
SELECT
, and
INSERT INTO ...
SELECT
.
This variable controls whether single-row
INSERT
statements produce an
information string if warnings occur. The default is 0. Set
the value to 1 to produce an information string.
Command-Line Format | --ssl-ca=name | ||
Option-File Format | ssl-ca | ||
Option Sets Variable | Yes, ssl_ca | ||
Variable Name | ssl-ca | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The path to a file with a list of trusted SSL CAs.
Command-Line Format | --ssl-capath=name | ||
Option-File Format | ssl-capath | ||
Option Sets Variable | Yes, ssl_capath | ||
Variable Name | ssl-capath | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name |
The path to a directory that contains trusted SSL CA certificates in PEM format.
Command-Line Format | --ssl-cert=name | ||
Option-File Format | ssl-cert | ||
Option Sets Variable | Yes, ssl_cert | ||
Variable Name | ssl-cert | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The name of the SSL certificate file to use for establishing a secure connection.
Command-Line Format | --ssl-cipher=name | ||
Option-File Format | ssl-cipher | ||
Option Sets Variable | Yes, ssl_cipher | ||
Variable Name | ssl-cipher | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
A list of permissible ciphers to use for SSL encryption.
Version Introduced | 5.6.3 | ||
Command-Line Format | --ssl-crl=name | ||
Option-File Format | ssl-crl | ||
Option Sets Variable | Yes, ssl_crl | ||
Variable Name | ssl-crl | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The path to a file containing certificate revocation lists in PEM format. Revocation lists work for MySQL distributions compiled against OpenSSL (but not yaSSL).
This variable was added in MySQL 5.6.3.
Version Introduced | 5.6.3 | ||
Command-Line Format | --ssl-crlpath=name | ||
Option-File Format | ssl-crlpath | ||
Option Sets Variable | Yes, ssl_crlpath | ||
Variable Name | ssl-crlpath | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | directory name |
The path to a directory that contains files containing certificate revocation lists in PEM format. Revocation lists work for MySQL distributions compiled against OpenSSL (but not yaSSL).
This variable was added in MySQL 5.6.3.
Command-Line Format | --ssl-key=name | ||
Option-File Format | ssl-key | ||
Option Sets Variable | Yes, ssl_key | ||
Variable Name | ssl-key | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The name of the SSL key file to use for establishing a secure connection.
Variable Name | storage_engine | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | InnoDB |
The default storage engine (table type). To set the storage
engine at server startup, use the
--default-storage-engine
option. See Section 5.1.3, “Server Command Options”.
This variable is deprecated. Use
default_storage_engine
instead.
Version Introduced | 5.6.5 | ||
Command-Line Format | --stored-program-cache=# | ||
Option-File Format | stored_program_cache | ||
Variable Name | stored_program_cache | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 256 | ||
Range | 256 .. 524288 |
Sets a soft upper limit for the number of cached stored routines per connection. The value of this variable is specified in terms of the number of stored routines held in each of the two caches maintained by the MySQL Server for, respectively, stored procedures and stored functions.
Whenever a stored routine is executed this cache size is checked before the first or top-level statement in the routine is parsed; if the number of routines of the same type (stored procedures or stored functions according to which is being executed) exceeds the limit specified by this variable, the corresponding cache is flushed and memory previously allocated for cached objects is freed. This allows the cache to be flushed safely, even when there are dependencies between stored routines.
Command-Line Format | --sync-frm | ||
Option-File Format | sync_frm | ||
Option Sets Variable | Yes, sync_frm | ||
Variable Name | sync_frm | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | TRUE |
If this variable is set to 1, when any nontemporary table is
created its .frm
file is synchronized to
disk (using fdatasync()
). This is slower
but safer in case of a crash. The default is 1.
Variable Name | system_time_zone | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The server system time zone. When the server begins executing,
it inherits a time zone setting from the machine defaults,
possibly modified by the environment of the account used for
running the server or the startup script. The value is used to
set system_time_zone
.
Typically the time zone is specified by the
TZ
environment variable. It also can be
specified using the
--timezone
option of the
mysqld_safe script.
The system_time_zone
variable
differs from time_zone
.
Although they might have the same value, the latter variable
is used to initialize the time zone for each client that
connects. See Section 10.6, “MySQL Server Time Zone Support”.
Command-Line Format | --table_definition_cache=# | ||
Option-File Format | table_definition_cache | ||
Option Sets Variable | Yes, table_definition_cache | ||
Variable Name | table_definition_cache | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.7) | |||
Type | numeric | ||
Default | 400 | ||
Range | 400 .. 524288 | ||
Permitted Values (>= 5.6.8) | |||
Type | numeric | ||
Default | -1 (autosized) | ||
Range | 400 .. 524288 |
The number of table definitions (from
.frm
files) that can be stored in the
definition cache. If you use a large number of tables, you can
create a large table definition cache to speed up opening of
tables. The table definition cache takes less space and does
not use file descriptors, unlike the normal table cache. The
minimum value is 400. The default value is based on the
following formula, capped to a limit of 2000:
400 + (table_open_cache / 2)
Before MySQL 5.6.8, the default is 400.
Command-Line Format | --table-open-cache=# | ||
Option-File Format | table_open_cache | ||
Variable Name | table_open_cache | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.7) | |||
Type | numeric | ||
Default | 400 | ||
Range | 400 .. 524288 | ||
Permitted Values (>= 5.6.8) | |||
Type | numeric | ||
Default | 2000 | ||
Range | 400 .. 524288 |
The number of open tables for all threads. Increasing this
value increases the number of file descriptors that
mysqld requires. You can check whether you
need to increase the table cache by checking the
Opened_tables
status
variable. See Section 5.1.6, “Server Status Variables”. If
the value of Opened_tables
is large and you do not use
FLUSH TABLES
often (which just forces all tables to be closed and
reopened), then you should increase the value of the
table_open_cache
variable.
For more information about the table cache, see
Section 8.4.3.1, “How MySQL Opens and Closes Tables”.
Version Introduced | 5.6.6 | ||
Command-Line Format | --table-open-cache_instances=# | ||
Option-File Format | table_open_cache_instances | ||
Variable Name | table_open_cache_instances | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | numeric | ||
Default | 1 |
The number of open tables cache instances (default 1). To
improve scalability by reducing contention among sessions, the
open tables cache can be partitioned into several smaller
cache instances of size
table_open_cache
/
table_open_cache_instances
.
A session need lock only one instance to access it for DML
statements. This segments cache access among instances,
permitting higher performance for operations that need to use
the cache when many there are many sessions accessing tables.
(DDL statements still require a lock on the entire cache, but
such statements are much less frequent than DML statements.)
A value of 8 or 16 is recommended on systems that routinely use 16 or more cores.
This variable was added in MySQL 5.6.6.
Command-Line Format | --thread_cache_size=# | ||
Option-File Format | thread_cache_size | ||
Option Sets Variable | Yes, thread_cache_size | ||
Variable Name | thread_cache_size | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values (<= 5.6.7) | |||
Type | numeric | ||
Default | 0 | ||
Range | 0 .. 16384 | ||
Permitted Values (>= 5.6.8) | |||
Type | numeric | ||
Default | -1 (autosized) | ||
Range | 0 .. 16384 |
How many threads the server should cache for reuse. When a
client disconnects, the client's threads are put in the cache
if there are fewer than
thread_cache_size
threads
there. Requests for threads are satisfied by reusing threads
taken from the cache if possible, and only when the cache is
empty is a new thread created. This variable can be increased
to improve performance if you have a lot of new connections.
Normally, this does not provide a notable performance
improvement if you have a good thread implementation. However,
if your server sees hundreds of connections per second you
should normally set
thread_cache_size
high enough
so that most new connections use cached threads. By examining
the difference between the
Connections
and
Threads_created
status
variables, you can see how efficient the thread cache is. For
details, see Section 5.1.6, “Server Status Variables”.
The default value is based on the following formula, capped to a limit of 100:
8 + (max_connections / 100)
Before MySQL 5.6.8, the default is 0.
Version Deprecated | 5.6.1 | ||
Command-Line Format | --thread_concurrency=# | ||
Option-File Format | thread_concurrency | ||
Option Sets Variable | Yes, thread_concurrency | ||
Variable Name | thread_concurrency | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Deprecated | 5.6.1 | ||
Permitted Values | |||
Type | numeric | ||
Default | 10 | ||
Range | 1 .. 512 |
This variable is specific to Solaris systems, for which
mysqld invokes the
thr_setconcurrency()
with the variable
value. This function enables applications to give the threads
system a hint about the desired number of threads that should
be run at the same time.
This variable is deprecated as of MySQL 5.6.1 and will be removed in a future MySQL release.
Command-Line Format | --thread_handling=name | ||
Option-File Format | thread_handling=name | ||
Option Sets Variable | Yes, thread_handling | ||
Variable Name | thread_handling | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | enumeration | ||
Valid Values |
|
The thread-handling model used by the server for connection
threads. The permissible values are
no-threads
(the server uses a single
thread) and one-thread-per-connection
(the
server uses one thread to handle each client connection).
no-threads
is useful for debugging under
Linux; see
MySQL
Internals: Porting to Other Systems.
Command-Line Format | --thread_stack=# | ||
Option-File Format | thread_stack | ||
Option Sets Variable | Yes, thread_stack | ||
Variable Name | thread_stack | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 196608 | ||
Range | 131072 .. 4294967295 | ||
Block Size | 1024 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 262144 | ||
Range | 131072 .. 18446744073709547520 | ||
Block Size | 1024 |
The stack size for each thread. Many of the limits detected by
the crash-me
test are dependent on this
value. See Section 8.12.2, “The MySQL Benchmark Suite”. The default of
192KB (256KB for 64-bit systems) is large enough for normal
operation. If the thread stack size is too small, it limits
the complexity of the SQL statements that the server can
handle, the recursion depth of stored procedures, and other
memory-consuming actions.
This variable is unused. It is deprecated as of MySQL 5.6.7 and will be removed in a future MySQL release.
Command-Line Format | --default_time_zone=string | ||
Option-File Format | default_time_zone | ||
Variable Name | time_zone | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | string |
The current time zone. This variable is used to initialize the
time zone for each client that connects. By default, the
initial value of this is 'SYSTEM'
(which
means, “use the value of
system_time_zone
”).
The value can be specified explicitly at server startup with
the --default-time-zone
option.
See Section 10.6, “MySQL Server Time Zone Support”.
Command-Line Format | --timed_mutexes | ||
Option-File Format | timed_mutexes | ||
Option Sets Variable | Yes, timed_mutexes | ||
Variable Name | timed_mutexes | ||
Variable Scope | Global | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
This variable controls whether InnoDB
mutexes are timed. If this variable is set to 0 or
OFF
(the default), mutex timing is
disabled. If the variable is set to 1 or
ON
, mutex timing is enabled. With timing
enabled, the os_wait_times
value in the
output from SHOW
ENGINE INNODB MUTEX
indicates the amount of time (in
ms) spent in operating system waits. Otherwise, the value is
0.
timestamp =
{
timestamp_value
|
DEFAULT}
Set the time for this client. This is used to get the original
timestamp if you use the binary log to restore rows.
timestamp_value
should be a Unix
epoch timestamp, not a MySQL timestamp.
As of MySQL 5.6.4, timestamp
is a DOUBLE
rather than
BIGINT
because its value includes a
microseconds part.
SET timestamp
affects the value returned by
NOW()
but not by
SYSDATE()
. This means that
timestamp settings in the binary log have no effect on
invocations of SYSDATE()
. The
server can be started with the
--sysdate-is-now
option to
cause SYSDATE()
to be an alias
for NOW()
, in which case
SET timestamp
affects both functions.
Command-Line Format | --tmp_table_size=# | ||
Option-File Format | tmp_table_size | ||
Option Sets Variable | Yes, tmp_table_size | ||
Variable Name | tmp_table_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | system dependent | ||
Range | 1024 .. 4294967295 |
The maximum size of internal in-memory temporary tables. (The
actual limit is determined as the minimum of
tmp_table_size
and
max_heap_table_size
.) If an
in-memory temporary table exceeds the limit, MySQL
automatically converts it to an on-disk
MyISAM
table. Increase the value of
tmp_table_size
(and
max_heap_table_size
if
necessary) if you do many advanced GROUP BY
queries and you have lots of memory. This variable does not
apply to user-created MEMORY
tables.
You can compare the number of internal on-disk temporary
tables created to the total number of internal temporary
tables created by comparing the values of the
Created_tmp_disk_tables
and
Created_tmp_tables
variables.
See also Section 8.4.3.3, “How MySQL Uses Internal Temporary Tables”.
Command-Line Format | --tmpdir=path | ||
-t | |||
Option-File Format | tmpdir | ||
Option Sets Variable | Yes, tmpdir | ||
Variable Name | tmpdir | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | file name |
The directory used for temporary files and temporary tables.
This variable can be set to a list of several paths that are
used in round-robin fashion. Paths should be separated by
colon characters (“:
”) on Unix
and semicolon characters (“;
”)
on Windows.
The multiple-directory feature can be used to spread the load
between several physical disks. If the MySQL server is acting
as a replication slave, you should not set
tmpdir
to point to a
directory on a memory-based file system or to a directory that
is cleared when the server host restarts. A replication slave
needs some of its temporary files to survive a machine restart
so that it can replicate temporary tables or
LOAD DATA
INFILE
operations. If files in the temporary file
directory are lost when the server restarts, replication
fails. You can set the slave's temporary directory using the
slave_load_tmpdir
variable.
In that case, the slave will not use the general
tmpdir
value and you can set
tmpdir
to a nonpermanent
location.
Command-Line Format | --transaction_alloc_block_size=# | ||
Option-File Format | transaction_alloc_block_size | ||
Option Sets Variable | Yes, transaction_alloc_block_size | ||
Variable Name | transaction_alloc_block_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 8192 | ||
Range | 1024 .. 4294967295 | ||
Block Size | 1024 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 8192 | ||
Range | 1024 .. 18446744073709547520 | ||
Block Size | 1024 |
The amount in bytes by which to increase a per-transaction
memory pool which needs memory. See the description of
transaction_prealloc_size
.
Command-Line Format | --transaction_prealloc_size=# | ||
Option-File Format | transaction_prealloc_size | ||
Option Sets Variable | Yes, transaction_prealloc_size | ||
Variable Name | transaction_prealloc_size | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Platform Bit Size | 32 | ||
Type | numeric | ||
Default | 4096 | ||
Range | 1024 .. 4294967295 | ||
Block Size | 1024 | ||
Permitted Values | |||
Platform Bit Size | 64 | ||
Type | numeric | ||
Default | 4096 | ||
Range | 1024 .. 18446744073709547520 | ||
Block Size | 1024 |
There is a per-transaction memory pool from which various
transaction-related allocations take memory. The initial size
of the pool in bytes is
transaction_prealloc_size
.
For every allocation that cannot be satisfied from the pool
because it has insufficient memory available, the pool is
increased by
transaction_alloc_block_size
bytes. When the transaction ends, the pool is truncated to
transaction_prealloc_size
bytes.
By making
transaction_prealloc_size
sufficiently large to contain all statements within a single
transaction, you can avoid many malloc()
calls.
Variable Name | tx_isolation | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | enumeration | ||
Default | REPEATABLE-READ | ||
Valid Values |
|
The default transaction isolation level. Defaults to
REPEATABLE-READ
.
This variable can be set directly, or indirectly using the
SET TRANSACTION
statement. See
Section 13.3.6, “SET TRANSACTION
Syntax”. If you set
tx_isolation
directly to an
isolation level name that contains a space, the name should be
enclosed within quotation marks, with the space replaced by a
dash. For example:
SET tx_isolation = 'READ-COMMITTED';
Any unique prefix of a valid value may be used to set the value of this variable.
The default transaction isolation level can also be set at
startup using the
--transaction-isolation
server
option.
Version Introduced | 5.6.5 | ||
Variable Name | tx_read_only | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | OFF |
The default transaction access mode. The value can be
OFF
(read/write, the default) or
ON
(read only).
This variable can be set directly, or indirectly using the
SET TRANSACTION
statement. See
Section 13.3.6, “SET TRANSACTION
Syntax”.
To set the default transaction access mode at startup, use the
--transaction-read-only
server
option.
This variable was added in MySQL 5.6.5.
Variable Name | unique_checks | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 1 |
If set to 1 (the default), uniqueness checks for secondary
indexes in InnoDB
tables are performed. If
set to 0, storage engines are permitted to assume that
duplicate keys are not present in input data. If you know for
certain that your data does not contain uniqueness violations,
you can set this to 0 to speed up large table imports to
InnoDB
.
Note that setting this variable to 0 does not require storage engines to ignore duplicate keys. An engine is still permitted to check for them and issue duplicate-key errors if it detects them.
Command-Line Format | --updatable_views_with_limit=# | ||
Option-File Format | updatable_views_with_limit | ||
Option Sets Variable | Yes, updatable_views_with_limit | ||
Variable Name | updatable_views_with_limit | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | boolean | ||
Default | 1 |
This variable controls whether updates to a view can be made
when the view does not contain all columns of the primary key
defined in the underlying table, if the update statement
contains a LIMIT
clause. (Such updates
often are generated by GUI tools.) An update is an
UPDATE
or
DELETE
statement. Primary key
here means a PRIMARY KEY
, or a
UNIQUE
index in which no column can contain
NULL
.
The variable can have two values:
1
or YES
: Issue a
warning only (not an error message). This is the default
value.
0
or NO
: Prohibit
the update.
validate_password_
xxx
The validate_password
plugin implements a
set of system variables having names of the form
validate_password_
.
These variables affect password testing by that plugin; see
Section 6.1.2.6.2, “Password Validation Plugin Options and Variables”.
xxx
The version number for the server. The value might also
include a suffix indicating server build or configuration
information. -log
indicates that one or
more of the general log, slow query log, or binary log are
enabled. -debug
indicates that the server was
built with debugging support enabled.
Variable Name | version_comment | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The CMake configuration program has a
COMPILATION_COMMENT
option that
permits a comment to be specified when building MySQL. This
variable contains the value of that comment. See
Section 2.9.4, “MySQL Source-Configuration Options”.
Variable Name | version_compile_machine | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The type of the server binary.
Variable Name | version_compile_os | ||
Variable Scope | Global | ||
Dynamic Variable | No | ||
Permitted Values | |||
Type | string |
The type of operating system on which MySQL was built.
Command-Line Format | --wait_timeout=# | ||
Option-File Format | wait_timeout | ||
Option Sets Variable | Yes, wait_timeout | ||
Variable Name | wait_timeout | ||
Variable Scope | Global, Session | ||
Dynamic Variable | Yes | ||
Permitted Values | |||
Type | numeric | ||
Default | 28800 | ||
Range | 1 .. 31536000 | ||
Permitted Values | |||
Type (windows) | numeric | ||
Default | 28800 | ||
Range | 1 .. 2147483 |
The number of seconds the server waits for activity on a noninteractive connection before closing it.
On thread startup, the session
wait_timeout
value is
initialized from the global
wait_timeout
value or from
the global
interactive_timeout
value,
depending on the type of client (as defined by the
CLIENT_INTERACTIVE
connect option to
mysql_real_connect()
). See
also interactive_timeout
.
The number of errors, warnings, and notes that resulted from
the last statement that generated messages. This variable is
read only. See Section 13.7.5.41, “SHOW WARNINGS
Syntax”.
The MySQL server maintains many system variables that indicate how
it is configured. Section 5.1.4, “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.2.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
global sql_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 gigabytes, 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-
at server startup. For example, to prevent the value of
var_name
=value
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.1.5.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.
. The
SUPER
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 for SESSION
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;
The @@
syntax for system variables is supported for compatibility with
some other database systems.
var_name
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 session 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
@@
(that is,
when you do not specify var_name
@@global.
or
@@session.
), MySQL returns the session value if
it exists and the global value otherwise. (This differs from
SET @@
, which always refers to
the session value.)
var_name
=
value
Some variables displayed by SHOW VARIABLES
may not be available using SELECT
@@
syntax; an
var_name
Unknown system variable
occurs. As a
workaround in such cases, you can use SHOW VARIABLES
LIKE '
.
var_name
'
Suffixes for specifying a value multiplier can be used when
setting a variable at server startup, but not to set the value
with SET
at runtime. On the other hand, with
SET
you
can assign a variable's value using an expression, which is not
true when you set a variable at server startup. For example, the
first of the following lines is legal at server startup, but the
second is not:
shell>mysql --max_allowed_packet=16M
shell>mysql --max_allowed_packet=16*1024*1024
Conversely, the second of the following lines is legal at runtime, but the first is not:
mysql>SET GLOBAL max_allowed_packet=16M;
mysql>SET GLOBAL max_allowed_packet=16*1024*1024;
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 | /home/mysql/ |
| 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 | /home/mysql/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_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.1.6-alpha-log |
| version_comment | Source distribution |
| version_compile_machine | i686 |
| version_compile_os | suse-linux |
| 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.6 supports one structured variable type, which specifies parameters governing the operation of key caches. A key cache structured variable has these components:
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 8.9.2, “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
, so
default
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
, and
local
are not legal instance names. This
avoids a conflict with notation such as
@@global.
for referring to nonstructured system variables.
var_name
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.1.5, “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 5.1.4, “Server System Variables”, 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.
Table 5.4. Dynamic Variable Summary
The server maintains many status variables that provide
information about its operation. You can view these variables and
their values by using the SHOW [GLOBAL | SESSION]
STATUS
statement (see Section 13.7.5.36, “SHOW STATUS
Syntax”).
The optional GLOBAL
keyword aggregates the
values over all connections, and SESSION
shows
the values for the current connection.
mysql> SHOW GLOBAL 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 following table lists all available server status variables:
Table 5.5. Status Variable Summary
The status variables have the following meanings.
The number of connections that were aborted because the client died without closing the connection properly. See Section C.5.2.11, “Communication Errors and Aborted Connections”.
The number of failed attempts to connect to the MySQL server. See Section C.5.2.11, “Communication Errors and Aborted Connections”.
For additional connection-related information, check the
Connection_errors_
status variables and the
xxx
host_cache
table.
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.
The number of nontransactional statements that caused the
binary log transaction cache to be written to disk is tracked
separately in the
Binlog_stmt_cache_disk_use
status variable.
The number of transactions that used the binary log cache.
The number of nontransaction statements that used the binary
log statement cache but that exceeded the value of
binlog_stmt_cache_size
and
used a temporary file to store those statements.
The number of nontransactional statements that used the binary log statement cache.
The number of bytes received from all clients.
The number of bytes sent to all clients.
The Com_
statement counter variables indicate the number of times each
xxx
xxx
statement has been executed.
There is one status variable for each type of statement. For
example, Com_delete
and
Com_insert
count
DELETE
and
INSERT
statements,
respectively. However, if a query result is returned from
query cache, the server increments the
Qcache_hits
status variable,
not Com_select
. See
Section 8.9.3.4, “Query Cache Status and Maintenance”.
All of the
Com_stmt_
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.
xxx
The Com_stmt_
status variables are as follows:
xxx
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_
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, xxx
Com_stmt_prepare
,
Com_stmt_execute
and
Com_stmt_close
also increase for
PREPARE
,
EXECUTE
, or
DEALLOCATE PREPARE
,
respectively. Additionally, the values of the older statement
counter variables Com_prepare_sql
,
Com_execute_sql
, and
Com_dealloc_sql
increase for the
PREPARE
,
EXECUTE
, and
DEALLOCATE PREPARE
statements.
Com_stmt_fetch
stands for the total number
of network round-trips issued when fetching from cursors.
Com_stmt_reprepare
indicates the number of
times statements were automatically reprepared by the server
after metadata changes to tables or views referred to by the
statement. A reprepare operation increments
Com_stmt_reprepare
, and also
Com_stmt_prepare
.
Whether the client connection uses compression in the client/server protocol.
These variables provide information about errors that occur during the client connection process. They are global only and represent error counts aggregated across connections from all hosts. These variables track errors not accounted for by the host cache (see Section 8.11.5.2, “DNS Lookup Optimization and the Host Cache”), such as errors that are not associated with TCP connections, occur very early in the connection process (even before an IP address is known), or are not specific to any particular IP address (such as out-of-memory conditions). These variables were added in MySQL 5.6.5.
The number of errors that occurred during calls to
accept()
on the listening port.
The number of connections refused due to internal errors in the server, such as failure to start a new thread or an out-of-memory condition.
Connection_errors_max_connections
The number of connections refused because the server
max_connections
limit was
reached.
The number of errors that occurred while searching for connecting client IP addresses.
The number of errors that occurred during calls to
select()
or poll()
on the listening port. (Failure of this operation does not
necessarily means a client connection was rejected.)
The number of connections refused by the
libwrap
library.
The number of connection attempts (successful or not) to the MySQL server.
The number of internal on-disk temporary tables created by the server while executing statements.
If an internal temporary table is created initially as an
in-memory table but becomes too large, MySQL automatically
converts it to an on-disk table. The maximum size for
in-memory temporary tables is the minimum of the
tmp_table_size
and
max_heap_table_size
values.
If Created_tmp_disk_tables
is large, you may want to increase the
tmp_table_size
or
max_heap_table_size
values.
value to lessen the likelihood that internal temporary tables
in memory will be converted to on-disk tables.
You can compare the number of internal on-disk temporary
tables created to the total number of internal temporary
tables created by comparing the values of the
Created_tmp_disk_tables
and
Created_tmp_tables
variables.
See also Section 8.4.3.3, “How MySQL Uses Internal Temporary Tables”.
How many temporary files mysqld has created.
The number of internal temporary tables created by the server while executing statements.
You can compare the number of internal on-disk temporary
tables created to the total number of internal temporary
tables created by comparing the values of the
Created_tmp_disk_tables
and
Created_tmp_tables
variables.
See also Section 8.4.3.3, “How MySQL Uses Internal Temporary Tables”.
Each invocation of the SHOW
STATUS
statement uses an internal temporary table
and increments the global
Created_tmp_tables
value.
The number of rows written with INSERT
DELAYED
for which some error occurred (probably
duplicate key
).
The number of INSERT DELAYED
handler threads in use for nontransactional tables.
The number of INSERT DELAYED
rows written to nontransactional tables.
The number of times the server flushes tables, whether because
a user executed a FLUSH
TABLES
statement or due to internal server
operation. It is also incremented by receipt of a
COM_REFRESH
packet. This is in contrast to
Com_flush
,
which indicates how many FLUSH
statements
have been executed, whether
FLUSH TABLES
,
FLUSH LOGS
,
and so forth.
The number of internal COMMIT
statements.
The number of times that rows have been deleted from tables.
The server increments this variable for each call to its
external_lock()
function, which generally
occurs at the beginning and end of access to a table instance.
There might be differences among storage engines. This
variable can be used, for example, to discover for a statement
that accesses a partitioned table how many partitions were
pruned before locking occurred: Check how much the counter
increased for the statement, subtract 2 (2 calls for the table
itself), then divide by 2 to get the number of partitions
locked. This variable was added in MySQL 5.6.2.
The number of times the server uses a storage engine's own Multi-Range Read implementation for table access. This variable was added in MySQL 5.6.1.
A counter for the prepare phase of two-phase commit operations.
The number of times the first entry in an index was read. 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 that col1
is
indexed.
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.
The number of requests to read the last key in an index. With
ORDER BY
, the server will issue a first-key
request followed by several next-key requests, whereas with
With ORDER BY DESC
, the server will issue a
last-key request followed by several previous-key requests.
This variable was added in MySQL 5.6.1.
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.
The number of requests to read the previous row in key order.
This read method is mainly used to optimize ORDER BY
... DESC
.
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 do not use keys properly.
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.
The number of requests for a storage engine to perform a rollback operation.
The number of requests for a storage engine to place a savepoint.
The number of requests for a storage engine to roll back to a savepoint.
The number of requests to update a row in a table.
The number of requests to insert a row in a table.
The total number of available InnoDB
undo logs. Supplements
the innodb_undo_logs
system
variable, which reports the number of active undo logs.
Innodb_buffer_pool_dump_status
The progress of an operation to record the
pages held in the
InnoDB
buffer pool, triggered
by the setting of
innodb_buffer_pool_dump_at_shutdown
or
innodb_buffer_pool_dump_now
.
Innodb_buffer_pool_load_status
The progress of an operation to
warm up the
InnoDB
buffer pool by reading
in a set of pages
corresponding to an earlier point in time, triggered by the
setting of
innodb_buffer_pool_load_at_startup
or
innodb_buffer_pool_load_now
.
If the operation introduces too much overhead, you can cancel
it by setting
innodb_buffer_pool_load_abort
.
The number of pages in the
InnoDB
buffer pool containing
data. The number includes both
dirty and clean pages.
Innodb_buffer_pool_pages_dirty
The current number of dirty
pages in the InnoDB
buffer pool.
Innodb_buffer_pool_pages_flushed
The number of requests to
flush
pages from the
InnoDB
buffer pool.
The number of free pages in
the InnoDB
buffer pool.
Innodb_buffer_pool_pages_latched
The number of latched pages
in the InnoDB
buffer pool. These are
pages currently being read or written, or that cannot be
flushed or removed for some
other reason. Calculation of this variable is expensive, so it
is available only when the UNIV_DEBUG
system is defined at server build time.
The number of pages in the
InnoDB
buffer pool 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
.
Innodb_buffer_pool_pages_total
The total size of the InnoDB
buffer pool, in
pages.
The number of pages read into
the InnoDB
buffer pool by the
read-ahead background
thread.
Innodb_buffer_pool_read_ahead_evicted
The number of pages read into
the InnoDB
buffer pool by the
read-ahead background
thread that were subsequently
evicted without having
been accessed by queries.
Innodb_buffer_pool_read_requests
The number of logical read requests made to the
InnoDB
buffer pool. These
requests could be serviced by returning data that was already
in memory, or by reading the data from disk into memory first.
The number of logical reads that InnoDB
could not satisfy from the
buffer pool, and had
to read directly from disk.
Normally, writes to the InnoDB
buffer pool happen in
the background. When InnoDB
needs to read
or create a page and no clean
pages are available, InnoDB
flushes some
dirty pages first and
waits for that operation to finish. This counter counts
instances of these waits. If
innodb_buffer_pool_size
has
been set properly, this value should be small.
Innodb_buffer_pool_write_requests
The number of writes done to the InnoDB
buffer pool.
The number of fsync()
operations so far.
The frequency of fsync()
calls is
influenced by the setting of the
innodb_flush_method
configuration option.
The current number of pending fsync()
operations. The frequency of fsync()
calls
is influenced by the setting of the
innodb_flush_method
configuration option.
The current number of pending reads.
The current number of pending writes.
The amount of data read since the server was started.
The total number of data reads.
The total number of data writes.
The amount of data written so far, in bytes.
The number of pages that have
been written to the
doublewrite
buffer. See Section 5.3.1, “InnoDB
Disk I/O”.
The number of doublewrite operations that have been performed.
See Section 5.3.1, “InnoDB
Disk I/O”.
Indicates whether the server was built with atomic instructions.
The number of times that the log buffer was too small and a wait was required for it to be flushed before continuing.
The number of write requests for the InnoDB
redo log.
The number of physical writes to the InnoDB
redo log file.
The number of files InnoDB
currently holds
open.
The number of fsync()
writes done to the
InnoDB
redo
log files.
The number of pending fsync()
operations
for the InnoDB
redo log files.
The number of pending writes to the InnoDB
redo log files.
The number of bytes written to the InnoDB
redo log files.
The compiled-in InnoDB
page size (default
16KB). Many values are counted in pages; the page size enables
them to be easily converted to bytes.
The number of pages created by operations on
InnoDB
tables.
The number of pages read by operations on
InnoDB
tables.
The number of pages written by operations on
InnoDB
tables.
The number of row locks
currently being waited for by operations on
InnoDB
tables.
The total time spent in acquiring
row locks for
InnoDB
tables, in milliseconds.
The average time to acquire a
row lock for
InnoDB
tables, in milliseconds.
The maximum time to acquire a
row lock for
InnoDB
tables, in milliseconds.
The number of times operations on InnoDB
tables had to wait for a row
lock.
The number of rows deleted from InnoDB
tables.
The number of rows inserted into InnoDB
tables.
The number of rows read from InnoDB
tables.
The number of rows updated in InnoDB
tables.
Innodb_truncated_status_writes
The number of times output from the SHOW ENGINE
INNODB STATUS
statement has been truncated.
The number of key blocks in the MyISAM
key
cache that have changed but have not yet been flushed to disk.
The number of unused blocks in the MyISAM
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.1.4, “Server System Variables”.
The number of used blocks in the MyISAM
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.
The number of requests to read a key block from the
MyISAM
key cache.
The number of physical reads of a key block from disk into the
MyISAM
key cache. If
Key_reads
is large, then
your key_buffer_size
value is
probably too small. The cache miss rate can be calculated as
Key_reads
/Key_read_requests
.
The number of requests to write a key block to the
MyISAM
key cache.
The number of physical writes of a key block from the
MyISAM
key cache to disk.
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. The default value
is 0. Last_query_cost
has
session scope.
The Last_query_cost
value
can be computed accurately only for simple “flat”
queries, not complex queries such as those with subqueries or
UNION
. For the latter, the
value is set to 0.
The number of iterations the query optimizer made in execution
plan construction for the previous query.
Last_query_cost
has session
scope. This variable was added in MySQL 5.6.5.
The maximum number of connections that have been in use simultaneously since the server started.
The number of rows waiting to be written to nontransactional
tables in INSERT DELAYED
queues.
The number of files that are open. This count includes regular files opened by the server. It does not include other types of files such as sockets or pipes. Also, the count does not include files that storage engines open using their own internal functions rather than asking the server level to do so.
The number of streams that are open (used mainly for logging).
The number of cached .frm
files.
The number of tables that are open.
The number of files that have been opened with
my_open()
(a mysys
library function). Parts of the server that open files without
using this function do not increment the count.
The number of .frm
files that have been
cached.
The number of tables that have been opened. If
Opened_tables
is big, your
table_open_cache
value is
probably too small.
Performance_schema_
xxx
Performance Schema status variables are listed in Section 20.12, “Performance Schema Status Variables”.
The current number of prepared statements. (The maximum number
of statements is given by the
max_prepared_stmt_count
system variable.)
The number of free memory blocks in the query cache.
The amount of free memory for the query cache.
The number of query cache hits.
The number of queries added to the query cache.
The number of queries that were deleted from the query cache because of low memory.
The number of noncached queries (not cacheable, or not cached
due to the query_cache_type
setting).
The number of queries registered in the query cache.
The total number of blocks in the query cache.
The number of statements executed by the server. This variable
includes statements executed within stored programs, unlike
the Questions
variable. It does not count
COM_PING
or
COM_STATISTICS
commands.
The number of statements executed by the server. This includes
only statements sent to the server by clients and not
statements executed within stored programs, unlike the
Queries
variable. This variable does not
count COM_PING
,
COM_STATISTICS
,
COM_STMT_PREPARE
,
COM_STMT_CLOSE
, or
COM_STMT_RESET
commands.
The number of semisynchronous slaves.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_net_avg_wait_time
The average time in microseconds the master waited for a slave reply.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_net_wait_time
The total time in microseconds the master waited for slave replies.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_net_waits
The total number of times the master waited for slave replies.
This variable is available only if the master-side semisynchronous replication plugin is installed.
The number of times the master turned off semisynchronous replication.
This variable is available only if the master-side semisynchronous replication plugin is installed.
The number of commits that were not acknowledged successfully by a slave.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Whether semisynchronous replication currently is operational
on the master. The value is ON
if the
plugin has been enabled and a commit acknowledgment has
occurred. It is OFF
if the plugin is not
enabled or the master has fallen back to asynchronous
replication due to commit acknowledgment timeout.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_timefunc_failures
The number of times the master failed when calling time
functions such as gettimeofday()
.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_tx_avg_wait_time
The average time in microseconds the master waited for each transaction.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_tx_wait_time
The total time in microseconds the master waited for transactions.
This variable is available only if the master-side semisynchronous replication plugin is installed.
The total number of times the master waited for transactions.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_wait_pos_backtraverse
The total number of times the master waited for an event with binary coordinates lower than events waited for previously. This can occur when the order in which transactions start waiting for a reply is different from the order in which their binary log events are written.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Rpl_semi_sync_master_wait_sessions
The number of sessions currently waiting for slave replies.
This variable is available only if the master-side semisynchronous replication plugin is installed.
The number of commits that were acknowledged successfully by a slave.
This variable is available only if the master-side semisynchronous replication plugin is installed.
Whether semisynchronous replication currently is operational
on the slave. This is ON
if the plugin has
been enabled and the slave I/O thread is running,
OFF
otherwise.
This variable is available only if the slave-side semisynchronous replication plugin is installed.
The RSA public key value used by the
sha256_password
authentication plugin. The
value is nonempty only if the server successfully initializes
the private and public keys in the files named by the
sha256_password_private_key_path
and
sha256_password_public_key_path
system variables. The value of
Rsa_public_key
comes from
the latter file.
For information about sha256_password
, see
Section 6.3.6.2, “The SHA-256 Authentication Plugin”.
This variable is available only if MySQL was built using OpenSSL. It was added in MySQL 5.6.6.
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.
The number of joins that used a range search on a reference table.
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.
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.
The number of joins that did a full scan of the first table.
Shows the replication heartbeat interval (in seconds) on a replication slave.
Shows when the most recent heartbeat signal was received by a
replication slave, as a
TIMESTAMP
value.
The number of temporary tables that the slave SQL thread currently has open. If the value is greater than zero, it is not safe to shut down the slave; see Section 16.4.1.22, “Replication and Temporary Tables”.
This counter increments with each replication heartbeat
received by a replication slave since the last time that the
slave was restarted or reset, or a CHANGE
MASTER TO
statement was issued.
The total number of times since startup that the replication slave SQL thread has retried transactions.
This is ON
if this server is a replication
slave that is connected to a replication master, and both the
I/O and SQL threads are running; otherwise, it is
OFF
.
The number of threads that have taken more than
slow_launch_time
seconds to
create.
The number of queries that have taken more than
long_query_time
seconds. See
Section 5.2.5, “The Slow Query Log”.
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.
The number of sorts that were done using ranges.
The number of sorted rows.
The number of sorts that were done by scanning the table.
The number of negotiates needed to establish the connection.
The number of accepted SSL connections.
The number of callback cache hits.
The current SSL cipher (empty for non-SSL connections).
The list of possible SSL ciphers.
The number of SSL connection attempts to an SSL-enabled master.
The number of negotiates needed to establish the connection to an SSL-enabled master.
The SSL context verification depth (how many certificates in the chain are tested).
The SSL context verification mode.
The default SSL timeout.
The number of successful SSL connections to the server.
The number of successful slave connections to an SSL-enabled master.
The last date for which the SSL certificate is valid. This variable was added in MySQL 5.6.3.
The first date for which the SSL certificate is valid. This variable was added in MySQL 5.6.3.
The number of SSL session cache hits.
The number of SSL session cache misses.
The SSL session cache mode.
The number of SSL session cache overflows.
The SSL session cache size.
The number of SSL session cache timeouts.
How many SSL connections were reused from the cache.
Ssl_used_session_cache_entries
How many SSL session cache entries were used.
The verification depth for replication SSL connections.
The verification mode for replication SSL connections.
The SSL protocol version of the connection.
The number of times that a request for a table lock could be granted immediately.
The number of times that a request for a table lock could not be granted 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.
The number of hits for open tables cache lookups. This variable was added in MySQL 5.6.6.
The number of misses for open tables cache lookups. This variable was added in MySQL 5.6.6.
The number of overflows for the open tables cache. This is the
number of times, after a table is opened or closed, a cache
instance has an unused entry and the size of the instance is
larger than table_open_cache
/ table_open_cache_instances
.
This variable was added in MySQL 5.6.6.
For the memory-mapped implementation of the log that is used
by mysqld when it acts as the transaction
coordinator for recovery of internal XA transactions, this
variable indicates the largest number of pages used for the
log since the server started. If the product of
Tc_log_max_pages_used
and
Tc_log_page_size
is always
significantly less than the log size, the size is larger than
necessary and can be reduced. (The size is set by the
--log-tc-size
option.
Currently, this variable is unused: It is unneeded for binary
log-based recovery, and the memory-mapped recovery log method
is not used unless the number of storage engines capable of
two-phase commit is greater than one.
(InnoDB
is the only applicable engine.)
The page size used for the memory-mapped implementation of the
XA recovery log. The default value is determined using
getpagesize()
. Currently, this variable is
unused for the same reasons as described for
Tc_log_max_pages_used
.
For the memory-mapped implementation of the recovery log, this
variable increments each time the server was not able to
commit a transaction and had to wait for a free page in the
log. If this value is large, you might want to increase the
log size (with the
--log-tc-size
option). For
binary log-based recovery, this variable increments each time
the binary log cannot be closed because there are two-phase
commits in progress. (The close operation waits until all such
transactions are finished.)
The number of threads in the thread cache.
The number of currently open connections.
The number of threads created to handle connections. If
Threads_created
is big, you
may want to increase the
thread_cache_size
value. The
cache miss rate can be calculated as
Threads_created
/Connections
.
The number of threads that are not sleeping.
The number of seconds that the server has been up.
The number of seconds since the most recent FLUSH
STATUS
statement.
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.
For answers to some questions that are often asked about server SQL modes in MySQL, see Section B.3, “MySQL 5.6 FAQ: Server SQL Mode”.
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.
When working with InnoDB
tables, consider also
the innodb_strict_mode
configuration option. It enables additional error checks for
InnoDB
tables, as listed in
Section 14.2.6.7, “InnoDB
Strict Mode”.
You can set the default SQL mode by starting
mysqld with the
--sql-mode="
option, or by using
modes
"sql-mode="
in modes
"my.cnf
(Unix operating systems) or
my.ini
(Windows).
modes
is a list of different modes
separated by comma (“,
”)
characters. The default SQL mode in MySQL 5.6.6 and later is
NO_ENGINE_SUBSTITUTION
; in MySQL 5.6.5 and
earlier, it was empty (no modes set). To clear the mode
explicitly, set it to an empty string using
--sql-mode=""
on the command line,
or with sql-mode=""
in
my.cnf
on Unix systems or in
my.ini
on Windows.
You can change the SQL mode at runtime by using a SET
[GLOBAL|SESSION]
sql_mode='
statement to
set the modes
'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.
SQL mode and user-defined partitioning. Changing the server SQL mode after creating and inserting data into partitioned tables can cause major changes in the behavior of such tables, and could lead to loss or corruption of data. It is strongly recommended that you never change the SQL mode once you have created tables employing user-defined partitioning.
When replicating partitioned tables, differing SQL modes on master and slave can also lead to problems. For best results, you should always use the same server SQL mode on the master and on the slave.
See Section 17.6, “Restrictions and Limitations on Partitioning”, for more information.
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:
This mode changes syntax and behavior to conform more closely to standard SQL. It is one of the special combination modes listed at the end of this section.
If a value could not be inserted as given into a transactional table, abort the statement. For a nontransactional 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.
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. It is one of the special combination modes listed at the end of this section.
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:
Do not perform 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
and
DATETIME
columns. It does not
apply TIMESTAMP
columns, which
always require a valid date.
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
permit such dates, enable
ALLOW_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. With
ANSI_QUOTES
enabled, you
cannot use double quotation marks 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 an INSERT
or
UPDATE
. If this mode is not
enabled, MySQL instead returns NULL
for
divisions by zero. For
INSERT
IGNORE
or UPDATE IGNORE
, MySQL
generates a warning for divisions by zero, but the result of
the operation is NULL
.
The precedence of the NOT
operator is such that expressions such as NOT a
BETWEEN b AND c
are parsed as NOT (a
BETWEEN b AND c)
. In some older versions of MySQL,
the expression was parsed as (NOT a) BETWEEN b AND
c
. The old higher-precedence behavior can be
obtained by enabling the
HIGH_NOT_PRECEDENCE
SQL
mode.
mysql>SET sql_mode = '';
mysql>SELECT NOT 1 BETWEEN -5 AND 5;
-> 0 mysql>SET sql_mode = 'HIGH_NOT_PRECEDENCE';
mysql>SELECT NOT 1 BETWEEN -5 AND 5;
-> 1
Permit spaces between a function name and the
“(
” character. This causes
built-in function names to be treated as reserved words. As a
result, identifiers that are the same as function names must
be quoted as described in Section 9.2, “Schema Object Names”. For
example, because there is a
COUNT()
function, the use of
count
as a table name in the following
statement causes an error:
mysql> CREATE TABLE count (i INT);
ERROR 1064 (42000): You have an error in your SQL syntax
The table name should be quoted:
mysql> CREATE TABLE `count` (i INT);
Query OK, 0 rows affected (0.00 sec)
The IGNORE_SPACE
SQL mode
applies to built-in functions, not to user-defined functions
or stored functions. It is always permissible to have spaces
after a UDF or stored function name, regardless of whether
IGNORE_SPACE
is enabled.
For further discussion of
IGNORE_SPACE
, see
Section 9.2.4, “Function Name Parsing and Resolution”.
Prevent the GRANT
statement
from automatically creating new users if it would otherwise do
so, unless authentication information is specified. The
statement must specify a nonempty password using
IDENTIFIED BY
or an authentication plugin
using IDENTIFIED WITH
.
NO_AUTO_VALUE_ON_ZERO
affects handling of AUTO_INCREMENT
columns.
Normally, you generate the next sequence number for the column
by inserting either NULL
or
0
into it.
NO_AUTO_VALUE_ON_ZERO
suppresses this behavior for 0
so that only
NULL
generates the next sequence number.
This mode can be useful if 0
has been
stored in a table's AUTO_INCREMENT
column.
(Storing 0
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 the
0
values, resulting in a table with
contents different from the one that was dumped. Enabling
NO_AUTO_VALUE_ON_ZERO
before
reloading the dump file solves this problem.
mysqldump now automatically includes in its
output a statement that enables
NO_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.
When creating a table, ignore all INDEX
DIRECTORY
and DATA DIRECTORY
directives. This option is useful on slave replication
servers.
Control automatic substitution of the default storage engine
when a statement such as CREATE
TABLE
or ALTER TABLE
specifies a storage engine that is disabled or not compiled
in.
Because storage engines can be pluggable at runtime, unavailable engines are treated the same way:
With NO_ENGINE_SUBSTITUTION
disabled, for CREATE TABLE
the
default engine is used and a warning occurs if the desired
engine is unavailable. For ALTER
TABLE
, a warning occurs and the table is not
altered.
With NO_ENGINE_SUBSTITUTION
enabled, an error occurs and the table is not created or
altered if the desired engine is unavailable.
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 of
SHOW CREATE TABLE
. This mode is
used by mysqldump in portability mode.
By default, subtraction between integer operands produces an
UNSIGNED
result if any operand
isUNSIGNED
. When
NO_UNSIGNED_SUBTRACTION
is
enabled, the subtraction result is signed, even if
any operand is unsigned. For example, compare the
type of column c2
in table
t1
with that of column
c2
in table t2
:
mysql>SET sql_mode='';
mysql>CREATE TABLE test (c1 BIGINT UNSIGNED NOT NULL);
mysql>CREATE TABLE t1 SELECT c1 - 1 AS c2 FROM test;
mysql>DESCRIBE t1;
+-------+---------------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------+---------------------+------+-----+---------+-------+ | c2 | bigint(21) unsigned | | | 0 | | +-------+---------------------+------+-----+---------+-------+ mysql>SET sql_mode='NO_UNSIGNED_SUBTRACTION';
mysql>CREATE TABLE t2 SELECT c1 - 1 AS c2 FROM test;
mysql>DESCRIBE t2;
+-------+------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------+------------+------+-----+---------+-------+ | c2 | bigint(21) | | | 0 | | +-------+------------+------+-----+---------+-------+
Note that this means that BIGINT UNSIGNED
is not 100% usable in all contexts. See
Section 12.10, “Cast Functions and Operators”.
mysql>SET sql_mode = '';
mysql>SELECT CAST(0 AS UNSIGNED) - 1;
+-------------------------+ | CAST(0 AS UNSIGNED) - 1 | +-------------------------+ | 18446744073709551615 | +-------------------------+ mysql>SET sql_mode = 'NO_UNSIGNED_SUBTRACTION';
mysql>SELECT CAST(0 AS UNSIGNED) - 1;
+-------------------------+ | CAST(0 AS UNSIGNED) - 1 | +-------------------------+ | -1 | +-------------------------+
In strict mode, do not permit '0000-00-00'
as a valid date. You can still insert zero dates with the
IGNORE
option. When not in strict mode, the
date is accepted but a warning is generated.
In strict mode, do not accept dates where the year part is
nonzero but the month or day part is 0 (for example,
'0000-00-00'
is legal but
'2010-00-01'
and
'2010-01-00'
are not). 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.
Do not permit queries for which the select list or
ORDER BY
list or HAVING
list refers to nonaggregated columns that are not named in the
GROUP BY
clause. The following query is
invalid with this mode enabled because
address
is not named in the GROUP
BY
clause:
mysql> SELECT name, address, MAX(age) FROM t GROUP BY name;
ERROR 1055 (42000): 't.address' isn't in GROUP BY
This mode also restricts references to nonaggregated columns
in the HAVING
clause that are not named in
the GROUP BY
clause.
mysql> SELECT name, MAX(age) FROM t GROUP BY name HAVING age < 30;
ERROR 1054 (42S22): Unknown column 'age' in 'having clause'
In addition, if a query has aggregate functions and no
GROUP BY
clause, it cannot have
nonaggregated columns in the select list or ORDER
BY
list:
mysql> SELECT name, MAX(age) FROM t;
ERROR 1140 (42000): Mixing of GROUP columns (MIN(),MAX(),COUNT(),...)
with no GROUP columns is illegal if there is no GROUP BY clause
For more information, see
Section 12.16.3, “MySQL Extensions to GROUP BY
”.
By default, trailing spaces are trimmed from
CHAR
column values on
retrieval. If
PAD_CHAR_TO_FULL_LENGTH
is
enabled, trimming does not occur and retrieved
CHAR
values are padded to their
full length. This mode does not apply to
VARCHAR
columns, for which
trailing spaces are retained on retrieval.
mysql>CREATE TABLE t1 (c1 CHAR(10));
Query OK, 0 rows affected (0.37 sec) mysql>INSERT INTO t1 (c1) VALUES('xy');
Query OK, 1 row affected (0.01 sec) mysql>SET sql_mode = '';
Query OK, 0 rows affected (0.00 sec) mysql>SELECT c1, CHAR_LENGTH(c1) FROM t1;
+------+-----------------+ | c1 | CHAR_LENGTH(c1) | +------+-----------------+ | xy | 2 | +------+-----------------+ 1 row in set (0.00 sec) mysql>SET sql_mode = 'PAD_CHAR_TO_FULL_LENGTH';
Query OK, 0 rows affected (0.00 sec) mysql>SELECT c1, CHAR_LENGTH(c1) FROM t1;
+------------+-----------------+ | c1 | CHAR_LENGTH(c1) | +------------+-----------------+ | xy | 10 | +------------+-----------------+ 1 row in set (0.00 sec)
Treat ||
as a
string concatenation operator (same as
CONCAT()
) rather than as a
synonym for OR
.
Treat REAL
as a synonym for
FLOAT
. By default, MySQL treats
REAL
as a synonym for
DOUBLE
.
Enable strict mode for all storage engines. Invalid data values are rejected. Additional detail follows.
Enable strict mode for transactional storage engines, and when possible for nontransactional storage engines. Additional details follow.
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
non-NULL
column that has no explicit
DEFAULT
clause in its definition. (For a
NULL
column, NULL
is
inserted if the value is missing.)
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 nontransactional 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 is 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.5, “Data Type Default Values”.
Strict mode disallows invalid date values such as
'2004-04-31'
. It does not disallow dates with
zero month or day 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.7.5.41, “SHOW WARNINGS
Syntax”.
Strict mode does not affect whether foreign key constraints are
checked. foreign_key_checks
can
be used for that. (See Section 5.1.4, “Server System Variables”.)
The following special modes are provided as shorthand for combinations of mode values from the preceding list.
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
.
ANSI
mode also causes the
server to return an error for queries where a set function
S
with an outer reference
cannot be aggregated in the outer query against which the
outer reference has been resolved. This is such a query:
S
(outer_ref
)
SELECT * FROM t1 WHERE t1.a IN (SELECT MAX(t1.b) FROM t2 WHERE ...);
Here, MAX(t1.b)
cannot
aggregated in the outer query because it appears in the
WHERE
clause of that query. Standard SQL
requires an error in this situation. If
ANSI
mode is not enabled,
the server treats
in such queries the same way that it would interpret
S
(outer_ref
)
.
S
(const
)
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
, and
NO_ENGINE_SUBSTITUTION
.
MySQL supports a plugin API that enables creation of server components. Plugins can be loaded at server startup, or loaded and unloaded at runtime without restarting the server. The components supported by this interface include, but are not limited to, storage engines, full-text parser plugins, partitioning support, and server extensions.
Server plugins must be loaded in to the server before they can be used. MySQL enables you to load a plugin at server startup or at runtime. It is also possible to control the activation of loaded plugins at startup, and to unload them at runtime.
Server plugins must be known to the server before they can be
used. A plugin can be made known several ways, as described
here. In the following descriptions,
plugin_name
stands for a plugin name
such as innodb
or csv
.
Built-in plugins:
A plugin that is built in to the server is known by the server
automatically. Normally, the server enables the plugin at
startup, although this can be changed with the
--
option.
plugin_name
Plugins registered in the
mysql.plugin
table:
The mysql.plugin
table serves as a registry
of plugins. The server normally enables each plugin listed in
the table at startup, although whether a given plugin is enabled
can be changed with the
--
option. If the server is started with the
plugin_name
--skip-grant-tables
option, it
does not consult this table and does not load the plugins listed
there.
Plugins named with command-line options:
A plugin that is located in a plugin library file can be loaded
at server startup with the
--plugin-load
option. Normally,
the server enables the plugin at startup, although this can be
changed with the
--
option.
plugin_name
The option value is a semicolon-separated list of
pairs. Each name
=plugin_library
name
is the name of the
plugin, and plugin_library
is the
name of the shared library that contains the plugin code. If a
plugin library is named without any preceding plugin name, the
server loads all plugins in the library. Each library file must
be located in the directory named by the
plugin_dir
system variable.
This option does not register any plugin in the
mysql.plugin
table. For subsequent restarts,
the server loads the plugin again only if
--plugin-load
is given again.
That is, this option effects a one-time installation that
persists only for one server invocation.
--plugin-load
enables plugins to
be loaded even when
--skip-grant-tables
is given
(which causes the server to ignore the
mysql.plugin
table).
--plugin-load
also enables
plugins to be loaded at startup under configurations when
plugins cannot be loaded at runtime.
The --plugin-load-add
option
complements the --plugin-load
option. --plugin-load-add
adds a
plugin or plugins to the set of plugins to be loaded at startup.
The argument format is the same as for
--plugin-load
.
--plugin-load-add
can be used to
avoid specifying a large set of plugins as a single long
unwieldy --plugin-load
. argument.
--plugin-load-add
can be given in
the absence of --plugin-load
, but
any instance of --plugin-load-add
that appears before
--plugin-load
. has no effect
because --plugin-load
resets the
set of plugins to load. In other words, these options:
--plugin-load=x --plugin-load-add=y
are equivalent to this option:
--plugin-load="x;y"
But these options:
--plugin-load-add=y --plugin-load=x
are equivalent to this option:
--plugin-load=x
Plugins installed with the
INSTALL PLUGIN
statement:
A plugin that is located in a plugin library file can be loaded
at runtime with the INSTALL
PLUGIN
statement. The statement also registers the
plugin in the mysql.plugin
table to cause the
server to load it on subsequent restarts. For this reason,
INSTALL PLUGIN
requires the
INSERT
privilege for the
mysql.plugin
table.
If a plugin is named both using a
--plugin-load
option and in the
mysql.plugin
table, the server starts but
writes these messages to the error log:
100310 19:15:44 [ERROR] Function 'plugin_name
' already exists 100310 19:15:44 [Warning] Couldn't load plugin named 'plugin_name
' with soname 'plugin_object_file
'.
Example: The --plugin-load
option
installs a plugin at server startup. To install a plugin named
myplugin
in a plugin library file named
somepluglib.so
, use these lines in a
my.cnf
file:
[mysqld] plugin-load=myplugin=somepluglib.so
In this case, the plugin is not registered in
mysql.plugin
. Restarting the server without
the --plugin-load
option causes
the plugin not to be loaded at startup.
Alternatively, the INSTALL PLUGIN
statement causes the server to load the plugin code from the
library file at runtime:
mysql> INSTALL PLUGIN myplugin SONAME 'somepluglib.so';
INSTALL PLUGIN
also causes
“permanent” plugin registration: The server lists
the plugin in the mysql.plugin
table to
ensure that it is loaded on subsequent server restarts.
Many plugins can be loaded either at server startup or at
runtime. However, if a plugin is designed such that it must be
loaded and initialized during server startup, use
--plugin-load
rather than
INSTALL PLUGIN
.
While a plugin is loaded, information about it is available at
runtime from several sources, such as the
INFORMATION_SCHEMA.PLUGINS
table
and the SHOW PLUGINS
statement.
For more information, see
Section 5.1.8.2, “Obtaining Server Plugin Information”.
If the server knows about a plugin when it starts (for example,
because the plugin is named using a
--plugin-load
option or
registered in the mysql.plugin
table), the
server loads and enables the plugin by default. It is possible
to control activation for such a plugin using a
--
startup option named after the plugin. In the following
descriptions, plugin_name
[=value
]plugin_name
stands for
a plugin name such as innodb
or
csv
. As with other options, dashes and
underscores are interchangeable in option names. For example,
--my_plugin=ON
and
--my-plugin=ON
are equivalent.
--
plugin_name
=OFF
Tells the server to disable the plugin.
--
plugin_name
[=ON]
Tells the server to enable the plugin. (Specifying the
option as
--
without a value has the same effect.) If the plugin fails to
initialize, the server runs with the plugin disabled.
plugin_name
--
plugin_name
=FORCE
Tells the server to enable the plugin, but if plugin initialization fails, the server does not start. In other words, this option forces the server to run with the plugin enabled or not at all.
--
plugin_name
=FORCE_PLUS_PERMANENT
Like FORCE
, but in addition prevents the
plugin from being unloaded at runtime. If a user attempts to
do so with UNINSTALL PLUGIN
,
an error occurs.
The values OFF
, ON
,
FORCE
, and
FORCE_PLUS_PERMANENT
are not case sensitive.
The activation state for plugins is visible in the
LOAD_OPTION
column of the
INFORMATION_SCHEMA.PLUGINS
table.
Suppose that CSV
,
BLACKHOLE
, and ARCHIVE
are
built-in pluggable storage engines and that you want the server
to load them at startup, subject to these conditions: The server
is permitted to run if CSV
initialization
fails, but must require that BLACKHOLE
initialization succeeds, and ARCHIVE
should
be disabled. To accomplish that, use these lines in an option
file:
[mysqld] csv=ON blackhole=FORCE archive=OFF
The
--enable-
option format is supported as a synonym for
plugin_name
--
.
The
plugin_name
=ON--disable-
and
plugin_name
--skip-
option formats are supported as synonyms for
plugin_name
--
.
plugin_name
=OFF
If a plugin is disabled, either explicitly with
OFF
or implicitly because it was enabled with
ON
but failed to initialize, aspects of
server operation that require the plugin will change. For
example, if the plugin implements a storage engine, existing
tables for the storage engine become inaccessible, and attempts
to create new tables for the storage engine result in tables
that use the default storage engine unless the
NO_ENGINE_SUBSTITUTION
SQL
mode has been enabled to cause an error to occur instead.
Disabling a plugin may require adjustment to other options. For
example, if you start the server using
--skip-innodb
to disable InnoDB
, other
innodb_
options likely will need to be omitted from the startup command.
In addition, because xxx
InnoDB
is the
default storage engine, it will not start unless you specify
another available storage engine with
--default_storage_engine
. As of
MySQL 5.6.3, you will also need to set
--default_tmp_storage_engine
.
A plugin known to the server can be uninstalled to disable it at
runtime with the UNINSTALL PLUGIN
statement. The statement unloads the plugin and removes it from
the mysql.plugin
table if it is registered
there. For this reason, UNINSTALL
PLUGIN
statement requires the
DELETE
privilege for the
mysql.plugin
table. With the plugin no longer
registered in the table, the server will not load the plugin
automatically for subsequent restarts.
UNINSTALL PLUGIN
can unload
plugins regardless of whether they were loaded with
INSTALL PLUGIN
or
--plugin-load
.
UNINSTALL PLUGIN
is subject to
these exceptions:
It cannot unload plugins that are built in to the server.
These can be identified as those that have a library name of
NULL
in the output from
INFORMATION_SCHEMA.PLUGINS
or
SHOW PLUGINS
.
It cannot unload plugins for which the server was started
with
--
,
which prevents plugin unloading at runtime. These can be
identified from the plugin_name
=FORCE_PLUS_PERMANENTLOAD_OPTION
column of
the INFORMATION_SCHEMA.PLUGINS
table.
There are several ways to determine which plugins are installed in the server:
The INFORMATION_SCHEMA.PLUGINS
table contains a row for each loaded plugin. Any that have a
PLUGIN_LIBRARY
value of
NULL
are built in and cannot be unloaded.
mysql> SELECT * FROM information_schema.PLUGINS\G
*************************** 1. row ***************************
PLUGIN_NAME: binlog
PLUGIN_VERSION: 1.0
PLUGIN_STATUS: ACTIVE
PLUGIN_TYPE: STORAGE ENGINE
PLUGIN_TYPE_VERSION: 50158.0
PLUGIN_LIBRARY: NULL
PLUGIN_LIBRARY_VERSION: NULL
PLUGIN_AUTHOR: MySQL AB
PLUGIN_DESCRIPTION: This is a pseudo storage engine to represent the binlog in a transaction
PLUGIN_LICENSE: GPL
LOAD_OPTION: FORCE
...
*************************** 10. row ***************************
PLUGIN_NAME: InnoDB
PLUGIN_VERSION: 1.0
PLUGIN_STATUS: ACTIVE
PLUGIN_TYPE: STORAGE ENGINE
PLUGIN_TYPE_VERSION: 50158.0
PLUGIN_LIBRARY: ha_innodb_plugin.so
PLUGIN_LIBRARY_VERSION: 1.0
PLUGIN_AUTHOR: Innobase Oy
PLUGIN_DESCRIPTION: Supports transactions, row-level locking,
and foreign keys
PLUGIN_LICENSE: GPL
LOAD_OPTION: ON
...
The SHOW PLUGINS
statement
displays a row for each loaded plugin. Any that have a
Library
value of NULL
are built in and cannot be unloaded.
mysql> SHOW PLUGINS\G
*************************** 1. row ***************************
Name: binlog
Status: ACTIVE
Type: STORAGE ENGINE
Library: NULL
License: GPL
...
*************************** 10. row ***************************
Name: InnoDB
Status: ACTIVE
Type: STORAGE ENGINE
Library: ha_innodb_plugin.so
License: GPL
...
The mysql.plugin
table shows which
plugins have been registered with
INSTALL PLUGIN
. The table
contains only plugin names and library file names, so it
does not provide as much information as the
PLUGINS
table or the
SHOW PLUGINS
statement.
Support for IPv6 in MySQL includes these capabilities:
MySQL Server can accept TCP/IP connections from clients connecting over IPv6. For example, this command connects over IPv6 to the MySQL server on the local host:
shell> mysql -h ::1
To use this capability, two things must be true:
Your system must be configured to support IPv6. See Section 5.1.9.1, “Verifying System Support for IPv6”.
The default MySQL server configuration permits only IPv4
connections, so the server must be configured for IPv6
connections. To permit IPv6 connections in addition to or
instead of IPv4 connections, start the server with an
appropriate --bind-address
option. See Section 5.1.4, “Server System Variables”.
MySQL account names permit IPv6 addresses to enable DBAs to
specify privileges for clients that connect to the server over
IPv6. See Section 6.2.3, “Specifying Account Names”. IPv6 addresses can
be specified in account names in statements such as
CREATE USER
,
GRANT
, and
REVOKE
. For example:
mysql>CREATE USER 'bill'@'::1' IDENTIFIED BY 'secret';
mysql>GRANT SELECT ON mydb.* TO 'bill'@'::1';
IPv6 functions enable conversion between string and internal
format IPv6 address formats, and checking whether values
represent valid IPv6 addresses. For example,
INET6_ATON()
and
INET6_NTOA()
are similar to
INET_ATON()
and
INET_NTOA()
, but handle IPv6
addresses in addition to IPv4 addresses. See
Section 12.15, “Miscellaneous Functions”.
The following sections describe how to set up MySQL so that clients can connect to the server over IPv6.
Before MySQL Server can accept IPv6 connections, the operating system on your server host must support IPv6. As a simple test to determine whether that is true, try this command:
shell> ping6 ::1
16 bytes from ::1, icmp_seq=0 hlim=64 time=0.171 ms
16 bytes from ::1, icmp_seq=1 hlim=64 time=0.077 ms
...
To produce a description of your system's network interfaces, invoke ifconfig -a and look for IPv6 addresses in the output.
If your host does not support IPv6, consult your system documentation for instructions on enabling it. It might be that you need only reconfigure an existing network interface to add an IPv6 address. Or a more extensive change might be needed, such as rebuilding the kernel with IPv6 options enabled.
These links may be helpful in setting up IPv6 on various platforms:
The MySQL server listens on a single network socket for TCP/IP
connections. This socket is bound to a single address, but it is
possible for an address to map onto multiple network interfaces.
To specify an address, use the
--bind-address=
option at server startup, where addr
addr
is an IPv4 or IPv6 address or a host name. (IPv6 addresses are
not supported before MySQL 5.5.3.) If
addr
is a host name, the server
resolves the name to an IP address and binds to that address.
The server treats different types of addresses as follows:
If the address is *
, the server accepts
TCP/IP connections on all server host IPv6 and IPv4
interfaces if the server host supports IPv6, or accepts
TCP/IP connections on all IPv4 addresses otherwise. Use this
address to permit both IPv4 and IPv6 connections on all
server interfaces. This value is permitted (and is the
default) as of MySQL 5.6.6.
If the address is 0.0.0.0
, the server
accepts TCP/IP connections on all server host IPv4
interfaces. This is the default before MySQL 5.6.6.
If the address is ::
, the server accepts
TCP/IP connections on all server host IPv4 and IPv6
interfaces. Use this address to permit both IPv4 and IPv6
connections on all server interfaces.
If the address is an IPv4-mapped address, the server accepts
TCP/IP connections for that address, in either IPv4 or IPv6
format. For example, if the server is bound to
::ffff:127.0.0.1
, clients can connect
using --host=127.0.0.1
or
--host=::ffff:127.0.0.1
.
If the address is a “regular” IPv4 or IPv6
address (such as 127.0.0.1
or
::1
), the server accepts TCP/IP
connections only for that IPv4 or IPv6 address.
If you intend to bind the server to a specific address, be sure
that the mysql.user
grant table contains an
account with administrative privileges that you can use to
connect to that address. Otherwise, you will not be able to shut
down the server. For example, if you bind the server to
*
, you can connect to it using all existing
accounts. But if you bind the server to ::1
,
it accepts connections only on that address. In that case, first
make sure that the 'root'@'::1'
account is
present in the mysql.user
table so you can
still connect to the server to shut it down.
The following procedure shows how to configure MySQL to permit
IPv6 connections by clients that connect to the local server
using the ::1
local host address. The
instructions given here assume that your system supports IPv6.
Start the MySQL server with an appropriate
--bind-address
option to
permit it to accept IPv6 connections. For example, put the
following lines in your server option file and restart the
server:
[mysqld] bind-address = * # before 5.6.6, use :: rather than *
Alternatively, you can bind the server to
::1
, but that makes the server more
restrictive for TCP/IP connections. It accepts only IPv6
connections for that single address and rejects IPv4
connections. For more information, see
Section 5.1.9.2, “Configuring the MySQL Server to Permit IPv6 Connections”.
As an administrator, connect to the server and create an
account for a local user who will connect from the
::1
local IPv6 host address:
mysql> CREATE USER 'ipv6user'@'::1' IDENTIFIED BY 'ipv6pass';
For the permitted syntax of IPv6 addresses in account names,
see Section 6.2.3, “Specifying Account Names”. In addition to the
CREATE USER
statement, you
can issue GRANT
statements
that give specific privileges to the account, although that
is not necessary for the remaining steps in this procedure.
Invoke the mysql client to connect to the server using the new account:
shell> mysql -h ::1 -u ipv6user -pipv6pass
Try some simple statements that show connection information:
mysql>STATUS
... Connection: ::1 via TCP/IP ... mysql>SELECT CURRENT_USER(), @@bind_address;
+----------------+----------------+ | CURRENT_USER() | @@bind_address | +----------------+----------------+ | ipv6user@::1 | :: | +----------------+----------------+
The following procedure shows how to configure MySQL to permit IPv6 connections by remote clients. It is similar to the preceding procedure for local clients, but the server and client hosts are distinct and each has its own nonlocal IPv6 address. The example uses these addresses:
Server host: 2001:db8:0:f101::1 Client host: 2001:db8:0:f101::2
These addresses are chosen from the nonroutable address range recommended by IANA for documentation purposes and suffice for testing on your local network. To accept IPv6 connections from clients outside the local network, the server host must have a public address. If your network provider assigns you an IPv6 address, you can use that. Otherwise, another way to obtain an address is to use an IPv6 broker; see Section 5.1.9.5, “Obtaining an IPv6 Address from a Broker”.
Start the MySQL server with an appropriate
--bind-address
option to
permit it to accept IPv6 connections. For example, put the
following lines in your server option file and restart the
server:
[mysqld] bind-address = * # before 5.6.6, use :: rather than *
Alternatively, you can bind the server to
2001:db8:0:f101::1
, but that makes the
server more restrictive for TCP/IP connections. It accepts
only IPv6 connections for that single address and rejects
IPv4 connections. For more information, see
Section 5.1.9.2, “Configuring the MySQL Server to Permit IPv6 Connections”.
On the server host (2001:db8:0:f101::1
),
create an account for a user who will connect from the
client host (2001:db8:0:f101::2
):
mysql> CREATE USER 'remoteipv6user'@'2001:db8:0:f101::2' IDENTIFIED BY 'remoteipv6pass';
On the client host (2001:db8:0:f101::2
),
invoke the mysql client to connect to the
server using the new account:
shell> mysql -h 2001:db8:0:f101::1 -u remoteipv6user -premoteipv6pass
Try some simple statements that show connection information:
mysql>STATUS
... Connection: 2001:db8:0:f101::1 via TCP/IP ... mysql>SELECT CURRENT_USER(), @@bind_address;
+-----------------------------------+----------------+ | CURRENT_USER() | @@bind_address | +-----------------------------------+----------------+ | remoteipv6user@2001:db8:0:f101::2 | :: | +-----------------------------------+----------------+
If you do not have a public IPv6 address that enables your system to communicate over IPv6 outside your local network, you can obtain one from an IPv6 broker. The Wikipedia IPv6 Tunnel Broker page lists several brokers and their features, such as whether they provide static addresses and the supported routing protocols.
After configuring your server host to use a broker-supplied IPv6
address, start the MySQL server with an appropriate
--bind-address
option to permit
the server to accept IPv6 connections. For example, put the
following lines in the server option file and restart the
server:
[mysqld] bind-address = * # before 5.6.6, use :: rather than *
Alternatively, you can bind the server to to the specific IPv6 address provided by the broker, but that makes the server more restrictive for TCP/IP connections. It accepts only IPv6 connections for that single address and rejects IPv4 connections. For more information, see Section 5.1.9.2, “Configuring the MySQL Server to Permit IPv6 Connections”. In addition, if the broker allocates dynamic addresses, the address provided for your system might change the next time you connect to the broker. If so, any accounts you create that name the original address become invalid. To bind to a specific address but avoid this change-of-address problem, you may be able to arrange with the broker for a static IPv6 address.
The following example shows how to use Freenet6 as the broker and the gogoc IPv6 client package on Gentoo Linux.
Create a account at Freenet6 by visiting this URL and signing up:
http://gogonet.gogo6.com
After creating the account, go to this URL, sign in, and create a user ID and password for the IPv6 broker:
http://gogonet.gogo6.com/page/freenet6-registration
As root
, install
gogoc:
shell> emerge gogoc
Edit /etc/gogoc/gogoc.conf
to set the
userid
and password
values. For example:
userid=gogouser passwd=gogopass
Start gogoc:
shell> /etc/init.d/gogoc start
To start gogoc each time your system boots, execute this command:
shell> rc-update add gogoc default
Use ping6 to try to ping a host:
shell> ping6 ipv6.google.com
To see your IPv6 address:
shell> ifconfig tun
MySQL Server supports a HELP
statement that returns online information from the MySQL Reference
manual (see Section 13.8.3, “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.
If you install MySQL using a binary or source 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.
If you upgrade MySQL using a binary distribution, the help tables
are not upgraded automatically, but you can upgrade them manually.
Locate the fill_help_tables.sql
file in the
share
or share/mysql
directory. Change location into that directory and process the
file with the mysql client as follows:
shell> mysql -u root mysql < fill_help_tables.sql
You can also obtain the latest
fill_help_tables.sql
at any time to upgrade
your help tables. Download the proper file for your version of
MySQL from http://dev.mysql.com/doc/index-other.html. After
downloading and uncompressing the file, process it with
mysql as described previously.
If you are working with Bazaar and a MySQL development source
tree, you will need to download the
fill_help_tables.sql
file because the tree
contains only a “stub” version.
On Unix, signals can be sent to processes. mysqld responds to signals sent to it as follows:
SIGTERM
causes the server to shut down.
SIGHUP
causes the server to reload the
grant tables and flush the logs (like
FLUSH
PRIVILEGES
and
FLUSH LOGS
).
It also writes a status report to the error log that has this
format:
Status information: Current dir: /var/mysql/data/ Running threads: 0 Stack size: 196608 Current locks: Key caches: default Buffer_size: 8388600 Block_size: 1024 Division_limit: 100 Age_limit: 300 blocks used: 0 not flushed: 0 w_requests: 0 writes: 0 r_requests: 0 reads: 0 handler status: read_key: 0 read_next: 0 read_rnd 0 read_first: 1 write: 0 delete 0 update: 0 Table status: Opened tables: 5 Open tables: 0 Open files: 7 Open streams: 0 Alarm status: Active alarms: 1 Max used alarms: 2 Next alarm time: 67
On some Mac OS X 10.3 versions, mysqld ignores
SIGHUP
and SIGQUIT
.
The server shutdown process takes place as follows:
The shutdown process is initiated.
This can occur 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 a SIGTERM
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 by closing the handlers for the network interfaces 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 associated with a client connection, the
server breaks the connection to the client and marks the
thread 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.7.6.4, “KILL
Syntax”, in particular for the instructions
about killed REPAIR TABLE
or
OPTIMIZE TABLE
operations on
MyISAM
tables.
For threads that have an open transaction, the transaction is
rolled back. Note that if a thread is updating a
nontransactional table, an operation such as a multiple-row
UPDATE
or
INSERT
may leave the table
partially updated because the operation can terminate before
completion.
If the server is a master replication server, it treats threads associated with currently connected slaves 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, it stops the I/O
and SQL threads, if they are active, before marking client
threads as killed. The SQL thread is permitted to finish its
current statement (to avoid causing replication problems), and
then stops. If the SQL thread is in the middle of a
transaction at this point, the server waits until the current
replication event group (if any) has finished executing, or
until the user issues a
KILL QUERY
or
KILL
CONNECTION
statement. See also
Section 13.4.2.6, “STOP SLAVE
Syntax”. Since non-transactional
statements cannot be rolled back, in order to guarantee
crash-safe replication, only transactional tables should be
used.
See also Section 16.2.2, “Replication Relay and Status Logs”).
The server shuts down or closes storage engines.
At this stage, the server flushes the table cache and closes all open tables.
Each storage engine performs any actions necessary for tables
that it manages.
InnoDB
flushes its buffer pool to disk
(unless innodb_fast_shutdown
is 2), writes the current LSN to the tablespace, and
terminates its own internal threads. MyISAM
flushes any pending index writes for a table.
The server exits.
MySQL Server has several logs that can help you find out what activity is taking place.
Log Type | Information Written to Log |
---|---|
Error log | Problems encountered starting, running, or stopping mysqld |
General query log | Established client connections and statements received from clients |
Binary log | Statements that change data (also used for replication) |
Relay log | Data changes received from a replication master server |
Slow query log | Queries that took more than
long_query_time seconds to
execute |
By default, no logs are enabled (except the error log on Windows). The following log-specific sections provide information about the server options that enable logging.
By default, the server writes files for all enabled logs in the data
directory. You can force the server to close and reopen the log
files (or in some cases switch to a new log file) by flushing the
logs. Log flushing occurs when you issue a
FLUSH LOGS
statement; execute mysqladmin with a
flush-logs
or refresh
argument; or execute mysqldump with a
--flush-logs
or
--master-data
option. See
Section 13.7.6.3, “FLUSH
Syntax”, Section 4.5.2, “mysqladmin — Client for Administering a MySQL Server”, and
Section 4.5.4, “mysqldump — A Database Backup Program”. In addition, the binary log is flushed
when its size reaches the value of the
max_binlog_size
system variable.
You can control the general query and slow query logs during runtime. You can enable or disable logging, or change the log file name. You can tell the server to write general query and slow query entries to log tables, log files, or both. For details, see Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”, Section 5.2.3, “The General Query Log”, and Section 5.2.5, “The Slow Query Log”.
The relay log is used only on slave replication servers, to hold data changes from the master server that must also be made on the slave. For discussion of relay log contents and configuration, see Section 16.2.2.1, “The Slave Relay Log”.
For information about log maintenance operations such as expiration of old log files, see Section 5.2.6, “Server Log Maintenance”.
For information about keeping logs secure, see Section 6.1.2.3, “Passwords and Logging”.
MySQL Server provides flexible control over the destination of
output to the general query log and the slow query log, if those
logs are enabled. Possible destinations for log entries are log
files or the general_log
and
slow_log
tables in the mysql
database. Either or both destinations can be selected.
Currently, logging to tables incurs significantly more server overhead than logging to files. If you enable the general log or slow query log and require highest performance, you should use file logging, not table logging.
Log control at server startup.
The --log-output
option specifies
the destination for log output. This option does not in itself
enable the logs. Its syntax is
--log-output[=
:
value
,...]
If --log-output
is given with a
value, the value should be a comma-separated list of one or
more of the words TABLE
(log to tables),
FILE
(log to files), or
NONE
(do not log to tables or files).
NONE
, if present, takes precedence over any
other specifiers.
If --log-output
is omitted, the
default logging destination is FILE
.
The general_log
system variable
controls logging to the general query log for the selected log
destinations. If specified at server startup,
general_log
takes an optional
argument of 1 or 0 to enable or disable the log. To specify a file
name other than the default for file logging, set the
general_log_file
variable.
Similarly, the slow_query_log
variable controls logging to the slow query log for the selected
destinations and setting
slow_query_log_file
specifies a
file name for file logging. If either log is enabled, the server
opens the corresponding log file and writes startup messages to
it. However, further logging of queries to the file does not occur
unless the FILE
log destination is selected.
Examples:
To write general query log entries to the log table and the
log file, use
--log-output=TABLE,FILE
to
select both log destinations and
--general_log
to enable the
general query log.
To write general and slow query log entries only to the log
tables, use --log-output=TABLE
to select tables as the log destination and
--general_log
and
--slow_query_log
to enable both
logs.
To write slow query log entries only to the log file, use
--log-output=FILE
to select
files as the log destination and
--slow_query_log
to enable the
slow query log. (In this case, because the default log
destination is FILE
, you could omit the
--log-output
option.)
Log control at runtime. The system variables associated with log tables and files enable runtime control over logging:
The global log_output
system
variable indicates the current logging destination. It can be
modified at runtime to change the destination.
The global general_log
and
slow_query_log
variables
indicate whether the general query log and slow query log are
enabled (ON
) or disabled
(OFF
). You can set these variables at
runtime to control whether the logs are enabled.
The global general_log_file
and slow_query_log_file
variables indicate the names of the general query log and slow
query log files. You can set these variables at server startup
or at runtime to change the names of the log files.
To disable or enable general query logging for the current
connection, set the session
sql_log_off
variable to
ON
or OFF
.
The use of tables for log output offers the following benefits:
Log entries have a standard format. To display the current structure of the log tables, use these statements:
SHOW CREATE TABLE mysql.general_log; SHOW CREATE TABLE mysql.slow_log;
Log contents are accessible through SQL statements. This enables the use of queries that select only those log entries that satisfy specific criteria. For example, to select log contents associated with a particular client (which can be useful for identifying problematic queries from that client), it is easier to do this using a log table than a log file.
Logs are accessible remotely through any client that can connect to the server and issue queries (if the client has the appropriate log table privileges). It is not necessary to log in to the server host and directly access the file system.
The log table implementation has the following characteristics:
In general, the primary purpose of log tables is to provide an interface for users to observe the runtime execution of the server, not to interfere with its runtime execution.
CREATE TABLE
,
ALTER TABLE
, and
DROP TABLE
are valid operations
on a log table. For ALTER TABLE
and DROP TABLE
, the log table
cannot be in use and must be disabled, as described later.
By default, the log tables use the CSV
storage engine that writes data in comma-separated values
format. For users who have access to the
.CSV
files that contain log table data,
the files are easy to import into other programs such as
spreadsheets that can process CSV input.
The log tables can be altered to use the
MyISAM
storage engine. You cannot use
ALTER TABLE
to alter a log
table that is in use. The log must be disabled first. No
engines other than CSV
or
MyISAM
are legal for the log tables.
To disable logging so that you can alter (or drop) a log
table, you can use the following strategy. The example uses
the general query log; the procedure for the slow query log is
similar but uses the slow_log
table and
slow_query_log
system
variable.
SET @old_log_state = @@global.general_log; SET GLOBAL general_log = 'OFF'; ALTER TABLE mysql.general_log ENGINE = MyISAM; SET GLOBAL general_log = @old_log_state;
TRUNCATE TABLE
is a valid
operation on a log table. It can be used to expire log
entries.
RENAME TABLE
is a valid
operation on a log table. You can atomically rename a log
table (to perform log rotation, for example) using the
following strategy:
USE mysql; DROP TABLE IF EXISTS general_log2; CREATE TABLE general_log2 LIKE general_log; RENAME TABLE general_log TO general_log_backup, general_log2 TO general_log;
CHECK TABLE
is a valid
operation on a log table.
LOCK TABLES
cannot be used on a
log table.
INSERT
,
DELETE
, and
UPDATE
cannot be used on a log
table. These operations are permitted only internally to the
server itself.
FLUSH TABLES WITH READ
LOCK
and the state of the global
read_only
system variable
have no effect on log tables. The server can always write to
the log tables.
Entries written to the log tables are not written to the binary log and thus are not replicated to slave servers. (Prior to MySQL 5.6.9, this was not always enforced orrectly. See Bug #14741537.)
To flush the log tables or log files, use
FLUSH TABLES
or FLUSH
LOGS
, respectively.
Partitioning of log tables is not permitted.
Before MySQL 5.6.6, mysqldump does not dump
the general_log
or
slow_query_log
tables for dumps of the
mysql
database. As of 5.6.6, the dump
includes statements to recreate those tables so that they are
not missing after reloading the dump file. Log table contents
are not dumped.
The error log contains information indicating when mysqld was started and stopped and also any critical errors that occur while the server is running. If mysqld notices a table that needs to be automatically checked or repaired, it writes a message to the error log.
On some operating systems, the error log contains a stack trace if mysqld dies. The trace can be used to determine where mysqld died. See MySQL Internals: Porting to Other Systems.
You can specify where mysqld writes the error
log with the
--log-error[=
option. If the option is given with no
file_name
]file_name
value,
mysqld uses the name
by
default. The server creates the file in the data directory unless
an absolute path name is given to specify a different directory.
host_name
.err
If you do not specify --log-error
,
or (on Windows) if you use the
--console
option, errors are
written to stderr
, the standard error output.
Usually this is your terminal.
On Windows, error output is always written to the error log if
--console
is not given.
In addition, on Windows, events and error messages are written to
the Windows Event Log within the Application log. Entries marked
as Warning
and Note
are
written to the Event Log, but informational messages (such as
information statements from individual storage engines) are not
copied to the Event Log. The log entries have a source of
MySQL. You cannot disable writing information
to the Windows Event Log.
If you flush the logs using
FLUSH LOGS
or
mysqladmin flush-logs and
mysqld is writing the error log to a file (for
example, if it was started with the
--log-error
option), the server
closes and reopens the log file. To rename the file, you can do so
manually before flushing. Then flushing the logs reopens a new
file with the original file name. For example, you can rename the
file and create a new one using the following commands:
shell>mv
shell>host_name
.errhost_name
.err-oldmysqladmin flush-logs
shell>mv
host_name
.err-oldbackup-directory
On Windows, use rename rather than mv.
No error log renaming occurs when the logs are flushed if the server is not writing to a named file.
If you use mysqld_safe to start
mysqld, mysqld_safe arranges
for mysqld to write error messages to a log
file or to syslog
.
mysqld_safe has three error-logging options,
--syslog
,
--skip-syslog
,
and --log-error
. The default
with no logging options or with
--skip-syslog
is to use the default log file. To explicitly specify use of an
error log file, specify
--log-error=
to mysqld_safe, and
mysqld_safe will arrange for
mysqld to write messages to a log file. To use
file_name
syslog
instead, specify the
--syslog
option.
If you specify --log-error
in an
option file in a [mysqld]
,
[server]
, or [mysqld_safe]
section, mysqld_safe will find and use the
option.
If mysqld_safe is used to start
mysqld and mysqld dies
unexpectedly, mysqld_safe notices that it needs
to restart mysqld and writes a
restarted mysqld
message to the error log.
The --log-warnings
option or
log_warnings
system variable can
be used to control warning logging to the error log. The default
value is enabled (1). Warning logging can be disabled using a
value of 0. If the value is greater than 1, aborted connections
are written to the error log, and access-denied errors for new
connection attempts are written. See
Section C.5.2.11, “Communication Errors and Aborted Connections”.
The general query log is a general record of what mysqld is doing. The server writes information to this log when clients connect or disconnect, and it logs each SQL statement received from clients. The general query log can be very useful when you suspect an error in a client and want to know exactly what the client sent to mysqld.
mysqld writes statements to the query log in the order that it receives them, which might differ from the order in which they are executed. This logging order contrasts to the binary log, for which statements are written after they are executed but before any locks are released. (Also, the query log contains all statements, whereas the binary log does not contain statements that only select data.)
By default, the general query log is disabled. To specify the
initial general query log state explicitly, use
--general_log[={0|1}]
. With no
argument or an argument of 1,
--general_log
enables the log. With
an argument of 0, this option disables the log. To specify a log
file name, use
--general_log_file=
.
To specify the log destination, use
file_name
--log-output
(as described in
Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”).
If you specify no name for the general query log file, the default
name is
. The
server creates the file in the data directory unless an absolute
path name is given to specify a different directory.
host_name
.log
To disable or enable the general query log or change the log file
name at runtime, use the global
general_log
and
general_log_file
system
variables. Set general_log
to 0
(or OFF
) to disable the log or to 1 (or
ON
) to enable it. Set
general_log_file
to specify the
name of the log file. If a log file already is open, it is closed
and the new file is opened.
When the general query log is enabled, the server writes output to
any destinations specified by the
--log-output
option or
log_output
system variable. If
you enable the log, the server opens the log file and writes
startup messages to it. However, further logging of queries to the
file does not occur unless the FILE
log
destination is selected. If the destination is
NONE
, the server writes no queries even if the
general log is enabled. Setting the log file name has no effect on
logging if the log destination value does not contain
FILE
.
Server restarts and log flushing do not cause a new general query log file to be generated (although flushing closes and reopens it). You can rename the file and create a new one by using the following commands:
shell>mv
shell>host_name
.loghost_name
-old.logmysqladmin flush-logs
shell>mv
host_name
-old.logbackup-directory
On Windows, use rename rather than mv.
You can also rename the general query log file at runtime by disabling the log:
SET GLOBAL general_log = 'OFF';
With the log disabled, rename the log file externally; for example, from the command line. Then enable the log again:
SET GLOBAL general_log = 'ON';
This method works on any platform and does not require a server restart.
The session sql_log_off
variable
can be set to ON
or OFF
to
disable or enable general query logging for the current
connection.
As of MySQL 5.6.3, passwords in statements written to the general
query log are rewritten by the server not to occur literally in
plain text. Password rewriting can be suppressed for the general
query log by starting the server with the
--log-raw
option. This option may
be useful for diagnostic purposes, to see the exact text of
statements as received by the server, but for security reasons is
not recommended for production use.
Before MySQL 5.6.3, passwords in statements are not rewritten and the general query log should be protected. See Section 6.1.2.3, “Passwords and Logging”.
The binary log contains “events” that describe
database changes such as table creation operations or changes to
table data. It also contains events for statements that
potentially could have made changes (for example, a
DELETE
which matched no rows),
unless row-based logging is used. The binary log also contains
information about how long each statement took that updated data.
The binary log has two important purposes:
For replication, the binary log on a master replication server provides a record of the data changes to be sent to slave servers. The master server sends the events contained in its binary log to its slaves, which execute those events to make the same data changes that were made on the master. See Section 16.2, “Replication Implementation”.
Certain data recovery operations require use of the binary log. After a backup has been restored, the events in the binary log that were recorded after the backup was made are re-executed. These events bring databases up to date from the point of the backup. See Section 7.5, “Point-in-Time (Incremental) Recovery Using the Binary Log”.
The binary log is not used for statements such as
SELECT
or
SHOW
that do not modify data. To
log all statements (for example, to identify a problem query), use
the general query log. See Section 5.2.3, “The General Query Log”.
Running a server with binary logging enabled makes performance slightly slower. However, the benefits of the binary log in enabling you to set up replication and for restore operations generally outweigh this minor performance decrement.
Beginning with MySQL 5.6.2, the binary log is crash-safe. Only complete events or transactions are logged or read back.
As of MySQL 5.6.3, passwords in statements written to the binary log are rewritten by the server not to occur literally in plain text. Before MySQL 5.6.3, passwords in statements are not rewritten and the binary log should be protected. See Section 6.1.2.3, “Passwords and Logging”.
The following discussion describes some of the server options and variables that affect the operation of binary logging. For a complete list, see Section 16.1.4.4, “Binary Log Options and Variables”.
To enable the binary log, start the server with the
--log-bin[=
option. If no base_name
]base_name
value is given,
the default name is the value of the pid-file
option (which by default is the name of host machine) followed by
-bin
. If the basename is given, the server
writes the file in the data directory unless the basename is given
with a leading absolute path name to specify a different
directory. It is recommended that you specify a basename
explicitly rather than using the default of the host name; see
Section C.5.8, “Known Issues in MySQL”, for the reason.
If you supply an extension in the log name (for example,
--log-bin=
),
the extension is silently removed and ignored.
base_name.extension
mysqld appends a numeric extension to the
binary log basename to generate binary log file names. The number
increases each time the server creates a new log file, thus
creating an ordered series of files. The server creates a new file
in the series each time it starts or flushes the logs. The server
also creates a new binary log file automatically after the current
log's size reaches
max_binlog_size
. A binary log
file may become larger than
max_binlog_size
if you are using
large transactions because a transaction is written to the file in
one piece, never split between files.
To keep track of which binary log files have been used,
mysqld also creates a binary log index file
that contains the names of all used binary log files. By default,
this has the same basename as the binary log file, with the
extension '.index'
. You can change the name of
the binary log index file with the
--log-bin-index[=
option. You should not manually edit this file while
mysqld is running; doing so would confuse
mysqld.
file_name
]
The term “binary log file” generally denotes an individual numbered file containing database events. The term “binary log” collectively denotes the set of numbered binary log files plus the index file.
A client that has the SUPER
privilege can disable binary logging of its own statements by
using a SET sql_log_bin=0
statement. See
Section 5.1.4, “Server System Variables”.
By default, the server logs the length of the event as well as the
event itself and uses this to verify that the event was written
correctly. You can also cause the server to write checksums for
the events by setting the
binlog_checksum
system variable.
When reading back from the binary log, the master uses the event
length by default, but can be made to use checksums if available
by enabling the
master_verify_checksum
system
variable. The slave I/O thread also verifies events received from
the master. You can cause the slave SQL thread to use checksums if
available when reading from the relay log by enabling the
slave_sql_verify_checksum
system
variable.
The format of the events recorded in the binary log is dependent on the binary logging format. Three format types are supported, row-based logging, statement-based logging and mixed-base logging. The binary logging format used depends on the MySQL version. For general descriptions of the logging formats, see Section 5.2.4.1, “Binary Logging Formats”. For detailed information about the format of the binary log, see MySQL Internals: The Binary Log.
The server evaluates the
--binlog-do-db
and
--binlog-ignore-db
options in the
same way as it does the
--replicate-do-db
and
--replicate-ignore-db
options. For
information about how this is done, see
Section 16.2.3.1, “Evaluation of Database-Level Replication and Binary Logging Options”.
A replication slave server by default does not write to its own
binary log any data modifications that are received from the
replication master. To log these modifications, start the slave
with the --log-slave-updates
option
in addition to the --log-bin
option
(see Section 16.1.4.3, “Replication Slave Options and Variables”). This is done
when a slave is also to act as a master to other slaves in chained
replication.
You can delete all binary log files with the
RESET MASTER
statement, or a subset
of them with PURGE BINARY LOGS
. See
Section 13.7.6.6, “RESET
Syntax”, and Section 13.4.1.1, “PURGE BINARY LOGS
Syntax”.
If you are using replication, you should not delete old binary log
files on the master until you are sure that no slave still needs
to use them. For example, if your slaves never run more than three
days behind, once a day you can execute mysqladmin
flush-logs on the master and then remove any logs that
are more than three days old. You can remove the files manually,
but it is preferable to use PURGE BINARY
LOGS
, which also safely updates the binary log index
file for you (and which can take a date argument). See
Section 13.4.1.1, “PURGE BINARY LOGS
Syntax”.
You can display the contents of binary log files with the mysqlbinlog utility. This can be useful when you want to reprocess statements in the log for a recovery operation. For example, you can update a MySQL server from the binary log as follows:
shell> mysqlbinlog log_file
| mysql -h server_name
mysqlbinlog also can be used to display replication slave relay log file contents because they are written using the same format as binary log files. For more information on the mysqlbinlog utility and how to use it, see Section 4.6.8, “mysqlbinlog — Utility for Processing Binary Log Files”. For more information about the binary log and recovery operations, see Section 7.5, “Point-in-Time (Incremental) Recovery Using the Binary Log”.
Binary logging is done immediately after a statement or transaction completes but before any locks are released or any commit is done. This ensures that the log is logged in commit order.
Updates to nontransactional tables are stored in the binary log immediately after execution.
Within an uncommitted transaction, all updates
(UPDATE
,
DELETE
, or
INSERT
) that change transactional
tables such as InnoDB
tables are cached until a
COMMIT
statement is received by the
server. At that point, mysqld writes the entire
transaction to the binary log before the
COMMIT
is executed.
Modifications to nontransactional tables cannot be rolled back. If
a transaction that is rolled back includes modifications to
nontransactional tables, the entire transaction is logged with a
ROLLBACK
statement at the end to ensure that the modifications to those
tables are replicated.
When a thread that handles the transaction starts, it allocates a
buffer of binlog_cache_size
to
buffer statements. If a statement is bigger than this, the thread
opens a temporary file to store the transaction. The temporary
file is deleted when the thread ends.
The Binlog_cache_use
status
variable shows the number of transactions that used this buffer
(and possibly a temporary file) for storing statements. The
Binlog_cache_disk_use
status
variable shows how many of those transactions actually had to use
a temporary file. These two variables can be used for tuning
binlog_cache_size
to a large
enough value that avoids the use of temporary files.
The max_binlog_cache_size
system
variable (default 4GB, which is also the maximum) can be used to
restrict the total size used to cache a multiple-statement
transaction. If a transaction is larger than this many bytes, it
fails and rolls back. The minimum value is 4096.
If you are using the binary log and row based logging, concurrent
inserts are converted to normal inserts for CREATE ...
SELECT
or
INSERT ...
SELECT
statements. This is done to ensure that you can
re-create an exact copy of your tables by applying the log during
a backup operation. If you are using statement-based logging, the
original statement is written to the log.
The binary log format has some known limitations that can affect recovery from backups. See Section 16.4.1, “Replication Features and Issues”.
Binary logging for stored programs is done as described in Section 18.7, “Binary Logging of Stored Programs”.
Note that the binary log format differs in MySQL 5.6 from previous versions of MySQL, due to enhancements in replication. See Section 16.4.2, “Replication Compatibility Between MySQL Versions”.
Writes to the binary log file and binary log index file are
handled in the same way as writes to MyISAM
tables. See Section C.5.4.3, “How MySQL Handles a Full Disk”.
By default, the binary log is not synchronized to disk at each
write. So if the operating system or machine (not only the MySQL
server) crashes, there is a chance that the last statements of the
binary log are lost. To prevent this, you can make the binary log
be synchronized to disk after every N
writes to the binary log, with the
sync_binlog
system variable. See
Section 5.1.4, “Server System Variables”. 1 is the safest value
for sync_binlog
, but also the
slowest. Even with sync_binlog
set to 1, there is still the chance of an inconsistency between
the table content and binary log content in case of a crash. For
example, if you are using InnoDB
tables and the
MySQL server processes a COMMIT
statement, it writes the whole transaction to the binary log and
then commits this transaction into InnoDB
. If
the server crashes between those two operations, the transaction
is rolled back by InnoDB
at restart but still
exists in the binary log. To resolve this, you should set
--innodb_support_xa
to 1. Although
this option is related to the support of XA transactions in
InnoDB, it also ensures that the binary log and InnoDB data files
are synchronized.
For this option to provide a greater degree of safety, the MySQL
server should also be configured to synchronize the binary log and
the InnoDB
logs to disk before committing the
transaction. The InnoDB
logs are synchronized
by default, and sync_binlog=1
can be used to
synchronize the binary log. The effect of this option is that at
restart after a crash, after doing a rollback of transactions, the
MySQL server cuts rolled back InnoDB
transactions from the binary log. This ensures that the binary log
reflects the exact data of InnoDB
tables, and
so, that the slave remains in synchrony with the master (not
receiving a statement which has been rolled back).
If the MySQL server discovers at crash recovery that the binary
log is shorter than it should have been, it lacks at least one
successfully committed InnoDB
transaction. This
should not happen if sync_binlog=1
and the
disk/file system do an actual sync when they are requested to
(some do not), so the server prints an error message The
binary log
. In this case, this binary log is not
correct and replication should be restarted from a fresh snapshot
of the master's data.
file_name
is shorter than
its expected size
The session values of the following system variables are written to the binary log and honored by the replication slave when parsing the binary log:
sql_mode
(except that the
NO_DIR_IN_CREATE
mode is not
replicated; see
Section 16.4.1.34, “Replication and Variables”)
The server uses several logging formats to record information in the binary log. The exact format employed depends on the version of MySQL being used. There are three logging formats:
Replication capabilities in MySQL originally were based on
propagation of SQL statements from master to slave. This is
called statement-based logging. You can
cause this format to be used by starting the server with
--binlog-format=STATEMENT
.
In row-based logging, the master writes
events to the binary log that indicate how individual table
rows are affected. You can cause the server to use row-based
logging by starting it with
--binlog-format=ROW
.
A third option is also available: mixed
logging. With mixed logging, statement-based
logging is used by default, but the logging mode switches
automatically to row-based in certain cases as described
below. You can cause MySQL to use mixed logging explicitly
by starting mysqld with the option
--binlog-format=MIXED
.
In MySQL 5.6, the default binary logging format is
STATEMENT
.
The logging format can also be set or limited by the storage engine being used. This helps to eliminate issues when replicating certain statements between a master and slave which are using different storage engines.
With statement-based replication, there may be issues with replicating nondeterministic statements. In deciding whether or not a given statement is safe for statement-based replication, MySQL determines whether it can guarantee that the statement can be replicated using statement-based logging. If MySQL cannot make this guarantee, it marks the statement as potentially unreliable and issues the warning, Statement may not be safe to log in statement format.
You can avoid these issues by using MySQL's row-based replication instead.
You can select the binary logging format explicitly by starting
the MySQL server with
--binlog-format=
.
The supported values for type
type
are:
STATEMENT
causes logging to be statement
based.
ROW
causes logging to be row based.
MIXED
causes logging to use mixed format.
In MySQL 5.6, the default binary logging format is
STATEMENT
.
The logging format also can be switched at runtime. To specify
the format globally for all clients, set the global value of the
binlog_format
system variable:
mysql>SET GLOBAL binlog_format = 'STATEMENT';
mysql>SET GLOBAL binlog_format = 'ROW';
mysql>SET GLOBAL binlog_format = 'MIXED';
An individual client can control the logging format for its own
statements by setting the session value of
binlog_format
:
mysql>SET SESSION binlog_format = 'STATEMENT';
mysql>SET SESSION binlog_format = 'ROW';
mysql>SET SESSION binlog_format = 'MIXED';
Each MySQL Server can set its own and only its own binary
logging format (true whether
binlog_format
is set with
global or session scope). This means that changing the logging
format on a replication master does not cause a slave to
change its logging format to match. (When using
STATEMENT
mode, the
binlog_format
system variable
is not replicated; when using MIXED
or
ROW
logging mode, it is replicated but is
ignored by the slave.) Changing the binary logging format on
the master while replication is ongoing, or without also
changing it on the slave can thus cause unexpected results, or
even cause replication to fail altogether.
To change the global or session
binlog_format
value, you must
have the SUPER
privilege.
In addition to switching the logging format manually, a slave
server may switch the format automatically.
This happens when the server is running in either
STATEMENT
or MIXED
format
and encounters an event in the binary log that is written in
ROW
logging format. In that case, the slave
switches to row-based replication temporarily for that event,
and switches back to the previous format afterward.
There are several reasons why a client might want to set binary logging on a per-session basis:
A session that makes many small changes to the database might want to use row-based logging.
A session that performs updates that match many rows in the
WHERE
clause might want to use
statement-based logging because it will be more efficient to
log a few statements than many rows.
Some statements require a lot of execution time on the master, but result in just a few rows being modified. It might therefore be beneficial to replicate them using row-based logging.
There are exceptions when you cannot switch the replication format at runtime:
From within a stored function or a trigger
If the NDBCLUSTER
storage
engine is enabled
If the session is currently in row-based replication mode and has open temporary tables
Trying to switch the format in any of these cases results in an error.
Switching the replication format at runtime is not recommended
when any temporary tables exist, because temporary tables are
logged only when using statement-based replication, whereas with
row-based replication they are not logged. With mixed
replication, temporary tables are usually logged; exceptions
happen with user-defined functions (UDFs) and with the
UUID()
function.
With the binary log format set to ROW
, many
changes are written to the binary log using the row-based
format. Some changes, however, still use the statement-based
format. Examples include all DDL (data definition language)
statements such as CREATE TABLE
,
ALTER TABLE
, or
DROP TABLE
.
The --binlog-row-event-max-size
option is available for servers that are capable of row-based
replication. Rows are stored into the binary log in chunks
having a size in bytes not exceeding the value of this option.
The value must be a multiple of 256. The default value is 1024.
When using statement-based logging for replication, it is possible for the data on the master and slave to become different if a statement is designed in such a way that the data modification is nondeterministic; that is, it is left to the will of the query optimizer. In general, this is not a good practice even outside of replication. For a detailed explanation of this issue, see Section C.5.8, “Known Issues in MySQL”.
For information about logs kept by replication slaves, see Section 16.2.2, “Replication Relay and Status Logs”.
When running in MIXED
logging format, the
server automatically switches from statement-based to row-based
logging under the following conditions:
When a function contains
UUID()
.
When one or more tables with
AUTO_INCREMENT
columns are updated and a
trigger or stored function is invoked. Like all other unsafe
statements, this generates a warning if
binlog_format = STATEMENT
.
For more information, see
Section 16.4.1.1, “Replication and AUTO_INCREMENT
”.
When the body of a view requires row-based replication, the
statement creating the view also uses it. For example, this
occurs when the statement creating a view uses the
UUID()
function.
When a call to a UDF is involved.
When any INSERT DELAYED
is
executed for a nontransactional table.
If a statement is logged by row and the session that executed the statement has any temporary tables, logging by row is used for all subsequent statements (except for those accessing temporary tables) until all temporary tables in use by that session are dropped.
This is true whether or not any temporary tables are actually logged.
Temporary tables cannot be logged using row-based format; thus, once row-based logging is used, all subsequent statements using that table are unsafe. The server approximates this condition by treating all statements executed during the session as unsafe until the session no longer holds any temporary tables.
When FOUND_ROWS()
or
ROW_COUNT()
is used. (Bug
#12092, Bug #30244)
When USER()
,
CURRENT_USER()
, or
CURRENT_USER
is used. (Bug
#28086)
When a statement refers to one or more system variables. (Bug #31168)
Exception. The following system variables, when used with session scope (only), do not cause the logging format to switch:
For information about determining system variable scope, see Section 5.1.5, “Using System Variables”.
For information about how replication treats
sql_mode
, see
Section 16.4.1.34, “Replication and Variables”.
When one of the tables involved is a log table in the
mysql
database.
When the LOAD_FILE()
function
is used. (Bug #39701)
A warning is generated if you try to execute a statement using
statement-based logging that should be written using row-based
logging. The warning is shown both in the client (in the
output of SHOW WARNINGS
) and
through the mysqld error log. A warning is
added to the SHOW WARNINGS
table each time such a statement is executed. However, only
the first statement that generated the warning for each client
session is written to the error log to prevent flooding the
log.
In addition to the decisions above, individual engines can also determine the logging format used when information in a table is updated. The logging capabilities of an individual engine can be defined as follows:
If an engine supports row-based logging, the engine is said to be row-logging capable.
If an engine supports statement-based logging, the engine is said to be statement-logging capable.
A given storage engine can support either or both logging formats. The following table lists the formats supported by each engine.
Storage Engine | Row Logging Supported | Statement Logging Supported |
---|---|---|
ARCHIVE | Yes | Yes |
BLACKHOLE | Yes | Yes |
CSV | Yes | Yes |
EXAMPLE | Yes | No |
FEDERATED | Yes | Yes |
HEAP | Yes | Yes |
InnoDB | Yes | Yes when the transaction isolation level is
REPEATABLE READ or
SERIALIZABLE ; No
otherwise. |
MyISAM | Yes | Yes |
MERGE | Yes | Yes |
NDBCLUSTER | Yes | No |
In MySQL 5.6, whether a statement is to be logged
and the logging mode to be used is determined according to the
type of statement (safe, unsafe, or binary injected), the binary
logging format (STATEMENT
,
ROW
, or MIXED
), and the
logging capabilities of the storage engine (statement capable,
row capable, both, or neither). Statements may be logged with or
without a warning; failed statements are not logged, but
generate errors in the log. This is shown in the following
decision table, where SLC
stands for “statement-logging capable” and
RLC stands for
“row-logging capable”.
Condition | Action | ||||
---|---|---|---|---|---|
Type | binlog_format | SLC | RLC | Error / Warning | Logged as |
* | * | No | No | Error: Cannot execute statement: Binary logging is impossible since at least one engine is involved that is both row-incapable and statement-incapable. | - |
Safe | STATEMENT | Yes | No | - | STATEMENT |
Safe | MIXED | Yes | No | - | STATEMENT |
Safe | ROW | Yes | No | Error: Cannot execute statement: Binary logging
is impossible since BINLOG_FORMAT =
ROW and at least one table uses a storage
engine that is not capable of row-based logging. | - |
Unsafe | STATEMENT | Yes | No | Warning: Unsafe statement binlogged in statement
format, since BINLOG_FORMAT =
STATEMENT | STATEMENT |
Unsafe | MIXED | Yes | No | Error: Cannot execute statement: Binary logging
of an unsafe statement is impossible when the storage
engine is limited to statement-based logging, even if
BINLOG_FORMAT = MIXED . | - |
Unsafe | ROW | Yes | No | Error: Cannot execute statement: Binary logging
is impossible since BINLOG_FORMAT =
ROW and at least one table uses a storage
engine that is not capable of row-based logging. | - |
Row Injection | STATEMENT | Yes | No | Error: Cannot execute row injection: Binary logging is not possible since at least one table uses a storage engine that is not capable of row-based logging. | - |
Row Injection | MIXED | Yes | No | Error: Cannot execute row injection: Binary logging is not possible since at least one table uses a storage engine that is not capable of row-based logging. | - |
Row Injection | ROW | Yes | No | Error: Cannot execute row injection: Binary logging is not possible since at least one table uses a storage engine that is not capable of row-based logging. | - |
Safe | STATEMENT | No | Yes | Error: Cannot execute statement: Binary logging
is impossible since BINLOG_FORMAT =
STATEMENT and at least one table uses a
storage engine that is not capable of statement-based
logging. | - |
Safe | MIXED | No | Yes | - | ROW |
Safe | ROW | No | Yes | - | ROW |
Unsafe | STATEMENT | No | Yes | Error: Cannot execute statement: Binary logging
is impossible since BINLOG_FORMAT =
STATEMENT and at least one table uses a
storage engine that is not capable of statement-based
logging. | - |
Unsafe | MIXED | No | Yes | - | ROW |
Unsafe | ROW | No | Yes | - | ROW |
Row Injection | STATEMENT | No | Yes | Error: Cannot execute row injection: Binary
logging is not possible since BINLOG_FORMAT =
STATEMENT . | - |
Row Injection | MIXED | No | Yes | - | ROW |
Row Injection | ROW | No | Yes | - | ROW |
Safe | STATEMENT | Yes | Yes | - | STATEMENT |
Safe | MIXED | Yes | Yes | - | ROW |
Safe | ROW | Yes | Yes | - | ROW |
Unsafe | STATEMENT | Yes | Yes | Warning: Unsafe statement binlogged in statement
format since BINLOG_FORMAT =
STATEMENT . | STATEMENT |
Unsafe | MIXED | Yes | Yes | - | ROW |
Unsafe | ROW | Yes | Yes | - | ROW |
Row Injection | STATEMENT | Yes | Yes | Error: Cannot execute row injection: Binary
logging is not possible because BINLOG_FORMAT =
STATEMENT . | - |
Row Injection | MIXED | Yes | Yes | - | ROW |
Row Injection | ROW | Yes | Yes | - | ROW |
When a warning is produced by the determination, a standard
MySQL warning is produced (and is available using
SHOW WARNINGS
). The information
is also written to the mysqld error log. Only
one error for each error instance per client connection is
logged to prevent flooding the log. The log message includes the
SQL statement that was attempted.
If a slave server was started with
--log-warnings
enabled, the slave
prints messages to the error log to provide information about
its status, such as the binary log and relay log coordinates
where it starts its job, when it is switching to another relay
log, when it reconnects after a disconnect, and so forth.
The contents of the grant tables in the mysql
database can be modified directly (for example, with
INSERT
or
DELETE
) or indirectly (for
example, with GRANT
or
CREATE USER
). Statements that
affect mysql
database tables are written to
the binary log using the following rules:
Data manipulation statements that change data in
mysql
database tables directly are logged
according to the setting of the
binlog_format
system
variable. This pertains to statements such as
INSERT
,
UPDATE
,
DELETE
,
REPLACE
,
DO
,
LOAD DATA
INFILE
, SELECT
, and
TRUNCATE TABLE
.
Statements that change the mysql
database
indirectly are logged as statements regardless of the value
of binlog_format
. This
pertains to statements such as
GRANT
,
REVOKE
,
SET PASSWORD
,
RENAME USER
,
CREATE
(all forms except
CREATE TABLE
... SELECT
), ALTER
(all forms),
and DROP
(all forms).
CREATE TABLE ...
SELECT
is a combination of data definition and data
manipulation. The CREATE TABLE
part is logged using statement format and the
SELECT
part is logged according
to the value of binlog_format
.
The slow query log consists of SQL statements that took more than
long_query_time
seconds to
execute and required at least
min_examined_row_limit
rows to be
examined. The minimum and default values of
long_query_time
are 0 and 10,
respectively. The value can be specified to a resolution of
microseconds. For logging to a file, times are written including
the microseconds part. For logging to tables, only integer times
are written; the microseconds part is ignored.
The time to acquire the initial table locks is not counted as execution time. mysqld writes a statement to the slow query log after it has been executed and after all locks have been released, so log order might differ from execution order.
By default, the slow query log is disabled. To specify the initial
slow query log state explicitly, use
--slow_query_log[={0|1}]
. With no
argument or an argument of 1,
--slow_query_log
enables the log.
With an argument of 0, this option disables the log. To specify a
log file name, use
--slow_query_log_file=
.
To specify the log destination, use
file_name
--log-output
(as described in
Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”).
If you specify no name for the slow query log file, the default
name is
.
The server creates the file in the data directory unless an
absolute path name is given to specify a different directory.
host_name
-slow.log
To disable or enable the slow query log or change the log file
name at runtime, use the global
slow_query_log
and
slow_query_log_file
system
variables. Set slow_query_log
to
0 (or OFF
) to disable the log or to 1 (or
ON
) to enable it. Set
slow_query_log_file
to specify
the name of the log file. If a log file already is open, it is
closed and the new file is opened.
When the slow query log is enabled, the server writes output to
any destinations specified by the
--log-output
option or
log_output
system variable. If
you enable the log, the server opens the log file and writes
startup messages to it. However, further logging of queries to the
file does not occur unless the FILE
log
destination is selected. If the destination is
NONE
, the server writes no queries even if the
slow query log is enabled. Setting the log file name has no effect
on logging if the log destination value does not contain
FILE
.
The server writes less information to the slow query log (and
binary log) if you use the
--log-short-format
option.
To include slow administrative statements such as
OPTIMIZE TABLE
,
ANALYZE TABLE
, and
ALTER TABLE
in the statements
written to the slow query log, use the
--log-slow-admin-statements
server
option.
To include queries that do not use indexes for row lookups in the
statements written to the slow query log, enable the
log_queries_not_using_indexes
system variable. When such queries are logged, the slow query log
may grow quickly. It is possible to put a rate limit on these
queries by setting the
log_throttle_queries_not_using_indexes
system variable. By default, this variable is 0, which means there
is no limit. Positive values impose a per-minute limit on logging
of queries that do not use indexes. The first such query opens a
60-second window within which the server logs queries up to the
given limit, then suppresses additional queries. If there are
suppressed queries when the window ends, the server logs a summary
that indicates how many there were and the aggregate time spent in
them. The next 60-second window begins when the server logs the
next query that does not use indexes.
The server uses the controlling parameters in the following order to determine whether to write a query to the slow query log:
The query must either not be an administrative statement, or
--log-slow-admin-statements
must have been specified.
The query must have taken at least
long_query_time
seconds, or
log_queries_not_using_indexes
must be enabled and the query used no indexes for row lookups.
The query must have examined at least
min_examined_row_limit
rows.
The query must not be suppressed according to the
log_throttle_queries_not_using_indexes
setting.
The server does not write queries handled by the query cache to the slow query log, nor queries that would not benefit from the presence of an index because the table has zero rows or one row.
By default, a replication slave does not write replicated queries
to the slow query log. To change this, use the
--log-slow-slave-statements
server
option.
As of MySQL 5.6.3, passwords in statements written to the slow query log are rewritten by the server not to occur literally in plain text. Before MySQL 5.6.3, passwords in statements are not rewritten and the slow query log should be protected. See Section 6.1.2.3, “Passwords and Logging”.
The slow query log can be used to find queries that take a long time to execute and are therefore candidates for optimization. However, examining a long slow query log can become a difficult task. To make this easier, you can process a slow query log file using the mysqldumpslow command to summarize the queries that appear in the log. See Section 4.6.9, “mysqldumpslow — Summarize Slow Query Log Files”.
As described in Section 5.2, “MySQL Server Logs”, MySQL Server can create several different log files to help you see what activity is taking place. However, you must clean up these files regularly to ensure that the logs do not take up too much disk space.
When using MySQL with logging enabled, you may want to back up and remove old log files from time to time and tell MySQL to start logging to new files. See Section 7.2, “Database Backup Methods”.
On a Linux (Red Hat) installation, you can use the
mysql-log-rotate
script for this. If you
installed MySQL from an RPM distribution, this script should have
been installed automatically. Be careful with this script if you
are using the binary log for replication. You should not remove
binary logs until you are certain that their contents have been
processed by all slaves.
On other systems, you must install a short script yourself that you start from cron (or its equivalent) for handling log files.
For the binary log, you can set the
expire_logs_days
system variable
to expire binary log files automatically after a given number of
days (see Section 5.1.4, “Server System Variables”). If you are
using replication, you should set the variable no lower than the
maximum number of days your slaves might lag behind the master. To
remove binary logs on demand, use the PURGE
BINARY LOGS
statement (see
Section 13.4.1.1, “PURGE BINARY LOGS
Syntax”).
You can force MySQL to start using new log files by flushing the
logs. Log flushing occurs when you issue a
FLUSH LOGS
statement or execute a mysqladmin flush-logs,
mysqladmin refresh, mysqldump
--flush-logs, or mysqldump
--master-data command. See Section 13.7.6.3, “FLUSH
Syntax”,
Section 4.5.2, “mysqladmin — Client for Administering a MySQL Server”, and Section 4.5.4, “mysqldump — A Database Backup Program”. In
addition, the binary log is flushed when its size reaches the
value of the max_binlog_size
system variable.
FLUSH LOGS
supports optional modifiers to enable selective flushing of
individual logs (for example,
FLUSH BINARY
LOGS
).
A log-flushing operation does the following:
If general query logging or slow query logging to a log file is enabled, the server closes and reopens the general query log file or slow query log file.
If binary logging is enabled, the server closes the current binary log file and opens a new log file with the next sequence number.
If the server was started with the
--log-error
option to cause the
error log to be written to a file, the server closes and
reopens the log file.
The server creates a new binary log file when you flush the logs.
However, it just closes and reopens the general and slow query log
files. To cause new files to be created on Unix, rename the
current log files before flushing them. At flush time, the server
opens new log files with the original names. For example, if the
general and slow query log files are named
mysql.log
and
mysql-slow.log
, you can use a series of
commands like this:
shell>cd
shell>mysql-data-directory
mv mysql.log mysql.old
shell>mv mysql-slow.log mysql-slow.old
shell>mysqladmin flush-logs
On Windows, use rename rather than mv.
At this point, you can make a backup of
mysql.old
and
mysql-slow.old
and then remove them from
disk.
A similar strategy can be used to back up the error log file, if there is one.
You can rename the general query log or slow query log at runtime by disabling the log:
SET GLOBAL general_log = 'OFF'; SET GLOBAL slow_query_log = 'OFF';
With the logs disabled, rename the log files externally; for example, from the command line. Then enable the logs again:
SET GLOBAL general_log = 'ON'; SET GLOBAL slow_query_log = 'ON';
This method works on any platform and does not require a server restart.
As a DBA, you must manage disk I/O to keep the I/O subsystem from
becoming saturated, and manage disk space to avoid filling up
storage devices. The ACID design
model requires a certain amount of I/O that might seem redundant,
but helps to ensure data reliability. Within these constraints,
InnoDB
tries to optimize the database work and
the organization of disk files to minimize the amount of disk I/O.
Sometimes, I/O is postponed until the database is not busy, or until
everything needs to be brought to a consistent state, such as during
a database restart after a fast
shutdown.
This section discusses the main considerations for I/O and disk
space with the default kind of MySQL tables (also known as
InnoDB
tables):
Controlling the amount of background I/O used to improve query performance.
Enabling or disabling features that provide extra durability at the expense of additional I/O.
Organizing tables into many small files, a few larger files, or a combination of both.
Balancing the size of redo log files against the I/O activity that occurs when the log files become full.
How to reorganize a table for optimal query performance.
InnoDB
uses asynchronous disk I/O where
possible, by creating a number of threads to handle I/O
operations, while permitting other database operations to proceed
while the I/O is still in progress. On Linux and Windows
platforms, InnoDB uses the available OS and library functions to
perform “native” asynchronous I/O. On other
platforms, InnoDB still uses I/O threads, but the threads may
actually wait for I/O requests to complete; this technique is
known as “simulated” asynchronous I/O.
If InnoDB can determine there is a high probability that data might be needed soon, it performs read-ahead operations to bring that data into the buffer pool so that it is available in memory. Making a few large read requests for contiguous data can be more efficient than making several small, spread-out requests. There are two read-ahead heuristics in InnoDB:
In sequential read-ahead, if InnoDB
notices
that the access pattern to a segment in the tablespace is
sequential, it posts in advance a batch of reads of database
pages to the I/O system.
In random read-ahead, if InnoDB
notices
that some area in a tablespace seems to be in the process of
being fully read into the buffer pool, it posts the remaining
reads to the I/O system.
InnoDB
uses a novel file flush technique
involving a structure called the
doublewrite buffer.
It adds safety to recovery following an operating system crash or
a power outage, and improves performance on most varieties of Unix
by reducing the need for fsync()
operations.
Before writing pages to a data file, InnoDB
first writes them to a contiguous tablespace area called the
doublewrite buffer. Only after the write and the flush to the
doublewrite buffer has completed does InnoDB
write the pages to their proper positions in the data file. If the
operating system crashes in the middle of a page write (causing a
torn page condition),
InnoDB
can later find a good copy of the page
from the doublewrite buffer during recovery.
The data files that you define in the configuration file form the
InnoDB
system tablespace.
The files are logically concatenated to form the tablespace. There
is no striping in use. Currently, you cannot define where within
the tablespace your tables are allocated. In a newly created
tablespace, InnoDB
allocates space starting
from the first data file.
To avoid the issues that come with storing all tables and indexes
inside the system tablespace, you can turn on the
innodb_file_per_table
configuration option,
which stores each newly created table in a separate tablespace
file (with extension .ibd
). For tables stored
this way, there is less fragmentation within the disk file, and
when the table is truncated, the space is returned to the
operating system rather than still being reserved by InnoDB within
the system tablespace.
Each tablespace consists of database
pages. Every tablespace in a
MySQL instance has the same page
size. By default, all tablespaces have a page size of 16KB;
you can reduce the page size to 8KB or 4KB by specifying the
innodb_page_size
option when you
create the MySQL instance.
The pages are grouped into
extents of size 1MB (64
consecutive 16KB pages, or 128 8KB pages, or 256 4KB pages). The
“files” inside a tablespace are called
segments in
InnoDB
. (These segments are different from the
rollback segment,
which actually contains many tablespace segments.)
When a segment grows inside the tablespace,
InnoDB
allocates the first 32 pages to it one
at a time. After that, InnoDB
starts to
allocate whole extents to the segment. InnoDB
can add up to 4 extents at a time to a large segment to ensure
good sequentiality of data.
Two segments are allocated for each index in
InnoDB
. One is for nonleaf nodes of the B-tree,
the other is for the leaf nodes. Keeping the leaf nodes contiguous
on disk enables better sequential I/O operations, because these
leaf nodes contain the actual table data.
Some pages in the tablespace contain bitmaps of other pages, and
therefore a few extents in an InnoDB
tablespace
cannot be allocated to segments as a whole, but only as individual
pages.
When you ask for available free space in the tablespace by issuing
a SHOW TABLE STATUS
statement,
InnoDB
reports the extents that are definitely
free in the tablespace. InnoDB
always reserves
some extents for cleanup and other internal purposes; these
reserved extents are not included in the free space.
When you delete data from a table, InnoDB
contracts the corresponding B-tree indexes. Whether the freed
space becomes available for other users depends on whether the
pattern of deletes frees individual pages or extents to the
tablespace. Dropping a table or deleting all rows from it is
guaranteed to release the space to other users, but remember that
deleted rows are physically removed only by the
purge operation, which happens
automatically some time after they are no longer needed for
transaction rollbacks or consistent reads. (See
Section 14.2.4.11, “InnoDB
Multi-Versioning”.)
To see information about the tablespace, use the Tablespace
Monitor. See Section 14.2.5.4, “SHOW ENGINE INNODB
STATUS
and the InnoDB
Monitors”.
The maximum row length, except for variable-length columns
(VARBINARY
,
VARCHAR
,
BLOB
and
TEXT
), is slightly less than half
of a database page. That is, the maximum row length is about 8000
bytes. LONGBLOB
and
LONGTEXT
columns
must be less than 4GB, and the total row length, including
BLOB
and
TEXT
columns, must be less than
4GB.
If a row is less than half a page long, all of it is stored
locally within the page. If it exceeds half a page,
variable-length columns are chosen for external off-page storage
until the row fits within half a page. For a column chosen for
off-page storage, InnoDB
stores the first 768
bytes locally in the row, and the rest externally into overflow
pages. Each such column has its own list of overflow pages. The
768-byte prefix is accompanied by a 20-byte value that stores the
true length of the column and points into the overflow list where
the rest of the value is stored.
Making your log files very large may reduce disk I/O during checkpointing. It often makes sense to set the total size of the log files as large as the buffer pool or even larger. Although in the past large log files could make crash recovery take excessive time, starting with MySQL 5.5, performance enhancements to crash recovery make it possible to use large log files with fast startup after a crash. (Strictly speaking, this performance improvement is available for MySQL 5.1 with the InnoDB Plugin 1.0.7 and higher. It is with MySQL 5.5 that this improvement is available in the default InnoDB storage engine.)
InnoDB
implements a
checkpoint mechanism known
as fuzzy
checkpointing. InnoDB
flushes modified
database pages from the buffer pool in small batches. There is no
need to flush the buffer pool in one single batch, which would
disrupt processing of user SQL statements during the checkpointing
process.
During crash recovery,
InnoDB
looks for a checkpoint label written to
the log files. It knows that all modifications to the database
before the label are present in the disk image of the database.
Then InnoDB
scans the log files forward from
the checkpoint, applying the logged modifications to the database.
Random insertions into or deletions from a secondary index can cause the index to become fragmented. Fragmentation means that the physical ordering of the index pages on the disk is not close to the index ordering of the records on the pages, or that there are many unused pages in the 64-page blocks that were allocated to the index.
One symptom of fragmentation is that a table takes more space than
it “should” take. How much that is exactly, is
difficult to determine. All InnoDB
data and
indexes are stored in B-trees, and their fill factor may vary from
50% to 100%. Another symptom of fragmentation is that a table scan
such as this takes more time than it “should” take:
SELECT COUNT(*) FROM t WHERE non_indexed_column
<> 12345;
The preceding query requires MySQL to perform a full table scan, the slowest type of query for a large table.
To speed up index scans, you can periodically perform a
“null” ALTER TABLE
operation, which causes MySQL to rebuild the table:
ALTER TABLE tbl_name
ENGINE=INNODB
Another way to perform a defragmentation operation is to use mysqldump to dump the table to a text file, drop the table, and reload it from the dump file.
If the insertions into an index are always ascending and records
are deleted only from the end, the InnoDB
filespace management algorithm guarantees that fragmentation in
the index does not occur.
In some cases, you might want to run multiple instances of MySQL on a single machine. You might want to test a new MySQL release while leaving an existing production setup undisturbed. Or you might want to give different users access to different mysqld servers that they manage themselves. (For example, you might be an Internet Service Provider that wants to provide independent MySQL installations for different customers.)
It is possible to use a different MySQL server binary per instance, or use the same binary for multiple instances, or any combination of the two approaches. For example, you might run a server from MySQL 5.5 and one from MySQL 5.6, to see how different versions handle a given workload. Or you might run multiple instances of the current production version, each managing a different set of databases.
Whether or not you use distinct server binaries, each instance that
you run must be configured with unique values for several operating
parameters. This eliminates the potential for conflict between
instances. Parameters can be set on the command line, in option
files, or by setting environment variables. See
Section 4.2.3, “Specifying Program Options”. To see the values used by a given
instance, connect to it and execute a SHOW
VARIABLES
statement.
The primary resource managed by a MySQL instance is the data
directory. Each instance should use a different data directory, the
location of which is specified using the
--datadir=
option. For methods of configuring each instance with its own data
directory, and warnings about the dangers of failing to do so, see
Section 5.4.1, “Setting Up Multiple Data Directories”.
path
In addition to using different data directories, several other options must have different values for each server instance:
--port
controls the port number
for TCP/IP connections. Alternatively, if the host has multiple
network addresses, you can use
--bind-address
to cause each
server to listen to a different address.
--socket
controls the Unix socket
file path on Unix or the named pipe name on Windows. On Windows,
it is necessary to specify distinct pipe names only for those
servers configured to permit named-pipe connections.
--shared-memory-base-name=
name
This option is used only on Windows. It designates the shared-memory name used by a Windows server to permit clients to connect using shared memory. It is necessary to specify distinct shared-memory names only for those servers configured to permit shared-memory connections.
This option indicates the path name of the file in which the server writes its process ID.
If you use the following log file options, their values must differ for each server:
For further discussion of log file options, see Section 5.2, “MySQL Server Logs”.
To achieve better performance, you can specify the following option differently for each server, to spread the load between several physical disks:
Having different temporary directories also makes it easier to determine which MySQL server created any given temporary file.
If you have multiple MySQL installations in different locations, you
can specify the base directory for each installation with the
--basedir=
option. This causes each instance to automatically use a different
data directory, log files, and PID file because the default for each
of those parameters is relative to the base directory. In that case,
the only other options you need to specify are the
path
--socket
and
--port
options. Suppose that you
install different versions of MySQL using tar
file binary distributions. These install in different locations, so
you can start the server for each installation using the command
bin/mysqld_safe under its corresponding base
directory. mysqld_safe determines the proper
--basedir
option to pass to
mysqld, and you need specify only the
--socket
and
--port
options to
mysqld_safe.
As discussed in the following sections, it is possible to start
additional servers by specifying appropriate command options or by
setting environment variables. However, if you need to run multiple
servers on a more permanent basis, it is more convenient to use
option files to specify for each server those option values that
must be unique to it. The
--defaults-file
option is useful for
this purpose.
Each MySQL Instance on a machine should have its own data
directory. The location is specified using the
--datadir=
option.
path
There are different methods of setting up a data directory for a new instance:
Create a new data directory.
Copy an existing data directory.
The following discussion provides more detail about each method.
Normally, you should never have two servers that update data in the same databases. This may lead to unpleasant surprises if your operating system does not support fault-free system locking. If (despite this warning) you run multiple servers using the same data directory and they have logging enabled, you must use the appropriate options to specify log file names that are unique to each server. Otherwise, the servers try to log to the same files.
Even when the preceding precautions are observed, this kind of
setup works only with MyISAM
and
MERGE
tables, and not with any of the other
storage engines. Also, this warning against sharing a data
directory among servers always applies in an NFS environment.
Permitting multiple MySQL servers to access a common data
directory over NFS is a very bad idea. The
primary problem is that NFS is the speed bottleneck. It is not
meant for such use. Another risk with NFS is that you must
devise a way to ensure that two or more servers do not interfere
with each other. Usually NFS file locking is handled by the
lockd
daemon, but at the moment there is no
platform that performs locking 100% reliably in every situation.
With this method, the data directory will be in the same state as when you first install MySQL. It will have the default set of MySQL accounts and no user data.
On Unix, initialize the data directory by running mysql_install_db. See Section 2.10.1, “Unix Postinstallation Procedures”.
On Windows, the data directory is included in the MySQL distribution:
MySQL Zip archive distributions for Windows contain an
unmodified data directory. You can unpack such a distribution
into a temporary location, then copy it
data
directory to where you are setting
up the new instance.
Windows MSI package installers create and set up the data
directory that the installed server will use, but also create
a pristine “template” data directory named
data
under the installation directory.
After an installation has been performed using an MSI package,
the template data directory can be copied to set up additional
MySQL instances.
With this method, any MySQL accounts or user data present in the data directory are carried over to the new data directory.
Stop the existing MySQL instance using the data directory. This must be a clean shutdown so that the instance flushes any pending changes to disk.
Copy the data directory to the location where the new data directory should be.
Copy the my.cnf
or
my.ini
option file used by the existing
instance. This serves as a basis for the new instance.
Modify the new option file so that any pathnames referring to the original data directory refer to the new data directory. Also, modify any other options that must be unique per instance, such as the TCP/IP port number and the log files. For a list of parameters that must be unique per instance, see Section 5.4, “Running Multiple MySQL Instances on One Machine”.
Start the new instance, telling it to use the new option file.
You can run multiple servers on Windows by starting them manually from the command line, each with appropriate operating parameters, or by installing several servers as Windows services and running them that way. General instructions for running MySQL from the command line or as a service are given in Section 2.3, “Installing MySQL on Microsoft Windows”. The following sections describe how to start each server with different values for those options that must be unique per server, such as the data directory. These options are listed in Section 5.4, “Running Multiple MySQL Instances on One Machine”.
The procedure for starting a single MySQL server manually from
the command line is described in
Section 2.3.4.5, “Starting MySQL from the Windows Command Line”. To start multiple
servers this way, you can specify the appropriate options on the
command line or in an option file. It is more convenient to
place the options in an option file, but it is necessary to make
sure that each server gets its own set of options. To do this,
create an option file for each server and tell the server the
file name with a --defaults-file
option when you run it.
Suppose that you want to run mysqld on port
3307 with a data directory of C:\mydata1
,
and mysqld-debug on port 3308 with a data
directory of C:\mydata2
. Use this
procedure:
Make sure that each data directory exists, including its own
copy of the mysql
database that contains
the grant tables.
Create two option files. For example, create one file named
C:\my-opts1.cnf
that looks like this:
[mysqld] datadir = C:/mydata1 port = 3307
Create a second file named
C:\my-opts2.cnf
that looks like this:
[mysqld] datadir = C:/mydata2 port = 3308
Use the --defaults-file
option to start each server with its own option file:
C:\>C:\mysql\bin\mysqld --defaults-file=C:\my-opts1.cnf
C:\>C:\mysql\bin\mysqld-debug --defaults-file=C:\my-opts2.cnf
Each server starts in the foreground (no new prompt appears until the server exits later), so you will need to issue those two commands in separate console windows.
To shut down the servers, connect to each using the appropriate port number:
C:\>C:\mysql\bin\mysqladmin --port=3307 shutdown
C:\>C:\mysql\bin\mysqladmin --port=3308 shutdown
Servers configured as just described permit clients to connect
over TCP/IP. If your version of Windows supports named pipes and
you also want to permit named-pipe connections, use the
mysqld or mysqld-debug
server and specify options that enable the named pipe and
specify its name. Each server that supports named-pipe
connections must use a unique pipe name. For example, the
C:\my-opts1.cnf
file might be written like
this:
[mysqld] datadir = C:/mydata1 port = 3307 enable-named-pipe socket = mypipe1
Modify C:\my-opts2.cnf
similarly for use by
the second server. Then start the servers as described
previously.
A similar procedure applies for servers that you want to permit
shared-memory connections. Enable such connections with the
--shared-memory
option and
specify a unique shared-memory name for each server with the
--shared-memory-base-name
option.
On Windows, a MySQL server can run as a Windows service. The procedures for installing, controlling, and removing a single MySQL service are described in Section 2.3.4.8, “Starting MySQL as a Windows Service”.
To set up multiple MySQL services, you must make sure that each instance uses a different service name in addition to the other parameters that must be unique per instance.
For the following instructions, suppose that you want to run the
mysqld server from two different versions of
MySQL that are installed at C:\mysql-5.5.9
and C:\mysql-5.6.10
,
respectively. (This might be the case if you are running 5.5.9
as your production server, but also want to conduct tests using
5.6.10.)
To install MySQL as a Windows service, use the
--install
or --install-manual
option. For information about these options, see
Section 2.3.4.8, “Starting MySQL as a Windows Service”.
Based on the preceding information, you have several ways to set up multiple services. The following instructions describe some examples. Before trying any of them, shut down and remove any existing MySQL services.
Approach 1: Specify the
options for all services in one of the standard option
files. To do this, use a different service name for each
server. Suppose that you want to run the 5.5.9
mysqld using the service name of
mysqld1
and the 5.6.10
mysqld using the service name
mysqld2
. In this case, you can use the
[mysqld1]
group for 5.5.9 and the
[mysqld2]
group for 5.6.10.
For example, you can set up C:\my.cnf
like this:
# options for mysqld1 service [mysqld1] basedir = C:/mysql-5.5.9 port = 3307 enable-named-pipe socket = mypipe1 # options for mysqld2 service [mysqld2] basedir = C:/mysql-5.6.10 port = 3308 enable-named-pipe socket = mypipe2
Install the services as follows, using the full server path names to ensure that Windows registers the correct executable program for each service:
C:\>C:\mysql-5.5.9\bin\mysqld --install mysqld1
C:\>C:\mysql-5.6.10\bin\mysqld --install mysqld2
To start the services, use the services manager, or use NET START with the appropriate service names:
C:\>NET START mysqld1
C:\>NET START mysqld2
To stop the services, use the services manager, or use NET STOP with the appropriate service names:
C:\>NET STOP mysqld1
C:\>NET STOP mysqld2
Approach 2: Specify options
for each server in separate files and use
--defaults-file
when you
install the services to tell each server what file to use.
In this case, each file should list options using a
[mysqld]
group.
With this approach, to specify options for the 5.5.9
mysqld, create a file
C:\my-opts1.cnf
that looks like this:
[mysqld] basedir = C:/mysql-5.5.9 port = 3307 enable-named-pipe socket = mypipe1
For the 5.6.10 mysqld, create
a file C:\my-opts2.cnf
that looks like
this:
[mysqld] basedir = C:/mysql-5.6.10 port = 3308 enable-named-pipe socket = mypipe2
Install the services as follows (enter each command on a single line):
C:\>C:\mysql-5.5.9\bin\mysqld --install mysqld1
--defaults-file=C:\my-opts1.cnf
C:\>C:\mysql-5.6.10\bin\mysqld --install mysqld2
--defaults-file=C:\my-opts2.cnf
When you install a MySQL server as a service and use a
--defaults-file
option, the
service name must precede the option.
After installing the services, start and stop them the same way as in the preceding example.
To remove multiple services, use mysqld
--remove for each one, specifying a service name
following the --remove
option. If
the service name is the default (MySQL
), you
can omit it.
One way is to run multiple MySQL instances on Unix is to compile different servers with different default TCP/IP ports and Unix socket files so that each one listens on different network interfaces. Compiling in different base directories for each installation also results automatically in a separate, compiled-in data directory, log file, and PID file location for each server.
Assume that an existing 5.5 server is configured for
the default TCP/IP port number (3306) and Unix socket file
(/tmp/mysql.sock
). To configure a new
5.6.10 server to have different operating parameters,
use a CMake command something like this:
shell>cmake . -DMYSQL_TCP_PORT=
port_number
\-DMYSQL_UNIX_ADDR=
file_name
\-DCMAKE_INSTALL_PREFIX=/usr/local/mysql-5.6.10
Here, port_number
and
file_name
must be different from the
default TCP/IP port number and Unix socket file path name, and the
CMAKE_INSTALL_PREFIX
value should
specify an installation directory different from the one under
which the existing MySQL installation is located.
If you have a MySQL server listening on a given port number, you can use the following command to find out what operating parameters it is using for several important configurable variables, including the base directory and Unix socket file name:
shell> mysqladmin --host=host_name
--port=port_number
variables
With the information displayed by that command, you can tell what option values not to use when configuring an additional server.
If you specify localhost
as the host name,
mysqladmin defaults to using a Unix socket file
connection rather than TCP/IP. To explicitly specify the
connection protocol, use the
--protocol={TCP|SOCKET|PIPE|MEMORY}
option.
You need not compile a new MySQL server just to start with a different Unix socket file and TCP/IP port number. It is also possible to use the same server binary and start each invocation of it with different parameter values at runtime. One way to do so is by using command-line options:
shell> mysqld_safe --socket=file_name
--port=port_number
To start a second server, provide different
--socket
and
--port
option values, and pass a
--datadir=
option to mysqld_safe so that the server uses a
different data directory.
path
Alternatively, put the options for each server in a different
option file, then start each server using a
--defaults-file
option that
specifies the path to the appropriate option file. For example, if
the option files for two server instances are named
/usr/local/mysql/my.cnf
and
/usr/local/mysql/my.cnf2
, start the servers
like this: command:
shell>mysqld_safe --defaults-file=/usr/local/mysql/my.cnf
shell>mysqld_safe --defaults-file=/usr/local/mysql/my.cnf2
Another way to achieve a similar effect is to use environment variables to set the Unix socket file name and TCP/IP port number:
shell>MYSQL_UNIX_PORT=/tmp/mysqld-new.sock
shell>MYSQL_TCP_PORT=3307
shell>export MYSQL_UNIX_PORT MYSQL_TCP_PORT
shell>mysql_install_db --user=mysql
shell>mysqld_safe --datadir=/path/to/datadir &
This is a quick way of starting a second server to use for testing. The nice thing about this method is that the environment variable settings apply to any client programs that you invoke from the same shell. Thus, connections for those clients are automatically directed to the second server.
Section 2.12, “Environment Variables”, includes a list of other environment variables you can use to affect MySQL programs.
On Unix, the mysqld_multi script provides another way to start multiple servers. See Section 4.3.4, “mysqld_multi — Manage Multiple MySQL Servers”.
To connect with a client program to a MySQL server that is listening to different network interfaces from those compiled into your client, you can use one of the following methods:
Start the client with
--host=
host_name
--port=
to connect using TCP/IP to a remote server, with
port_number
--host=127.0.0.1
--port=
to connect using TCP/IP to a local server, or with
port_number
--host=localhost
--socket=
to connect to a local server using a Unix socket file or a
Windows named pipe.
file_name
Start the client with
--protocol=TCP
to connect
using TCP/IP,
--protocol=SOCKET
to connect
using a Unix socket file,
--protocol=PIPE
to connect
using a named pipe, or
--protocol=MEMORY
to connect
using shared memory. For TCP/IP connections, you may also need
to specify --host
and
--port
options. For the other
types of connections, you may need to specify a
--socket
option to specify a
Unix socket file or Windows named-pipe name, or a
--shared-memory-base-name
option to specify the shared-memory name. Shared-memory
connections are supported only on Windows.
On Unix, set the MYSQL_UNIX_PORT
and
MYSQL_TCP_PORT
environment variables to
point to the Unix socket file and TCP/IP port number before
you start your clients. If you normally use a specific socket
file or port number, you can place commands to set these
environment variables in your .login
file
so that they apply each time you log in. See
Section 2.12, “Environment Variables”.
Specify the default Unix socket file and TCP/IP port number in
the [client]
group of an option file. For
example, you can use C:\my.cnf
on
Windows, or the .my.cnf
file in your home
directory on Unix. See Section 4.2.3.3, “Using Option Files”.
In a C program, you can specify the socket file or port number
arguments in the
mysql_real_connect()
call. You
can also have the program read option files by calling
mysql_options()
. See
Section 21.9.3, “C API Function Descriptions”.
If you are using the Perl DBD::mysql
module, you can read options from MySQL option files. For
example:
$dsn = "DBI:mysql:test;mysql_read_default_group=client;" . "mysql_read_default_file=/usr/local/mysql/data/my.cnf"; $dbh = DBI->connect($dsn, $user, $password);
See Section 21.11, “MySQL Perl API”.
Other programming interfaces may provide similar capabilities for reading option files.
The DTrace probes in the MySQL server are designed to provide
information about the execution of queries within MySQL and the
different areas of the system being utilized during that process.
The organization and triggering of the probes means that the
execution of an entire query can be monitored with one level of
probes (query-start
and
query-done
) but by monitoring other probes you
can get successively more detailed information about the execution
of the query in terms of the locks used, sort methods and even
row-by-row and storage-engine level execution information.
The DTrace probes are organized so that you can follow the entire query process, from the point of connection from a client, through the query execution, row-level operations, and back out again. You can think of the probes as being fired within a specific sequence during a typical client connect/execute/disconnect sequence, as shown in the following figure.
Global information is provided in the arguments to the DTrace probes
at various levels. Global information, that is, the connection ID
and user/host and where relevant the query string, is provided at
key levels (connection-start
,
command-start
, query-start
,
and query-exec-start
). As you go deeper into the
probes, it is assumed either you are only interested in the
individual executions (row-level probes provide information on the
database and table name only), or that you will combine the
row-level probes with the notional parent probes to provide the
information about a specific query. Examples of this will be given
as the format and arguments of each probe are provided.
For more information on DTrace and writing DTrace scripts, read the DTrace User Guide.
MySQL 5.6 includes support for DTrace probes on Solaris
10 Update 5 (Solaris 5/08) on SPARC, x86 and x86_64 platforms.
Probes are also supported on Mac OS X 10.4 and higher. Enabling the
probes should be automatic on these platforms. To explicitly enable
or disable the probes during building, use the
-DENABLE_DTRACE=1
or
-DENABLE_DTRACE=0
option to
CMake.
MySQL supports the following static probes, organized into groups of functionality.
Table 5.6. MySQL DTrace Probes
Group | Probes | Introduced |
---|---|---|
Connection | connection-start , connection-done | 5.4.0 |
Command | command-start , command-done | 5.4.0 |
Query | query-start , query-done | 5.4.0 |
Query Parsing | query-parse-start ,
query-parse-done | 5.4.0 |
Query Cache | query-cache-hit , query-cache-miss | 5.4.0 |
Query Execution | query-exec-start , query-exec-done | 5.4.0 |
Row Level | insert-row-start , insert-row-done | 5.4.0 |
update-row-start , update-row-done | 5.4.0 | |
delete-row-start , delete-row-done | 5.4.0 | |
Row Reads | read-row-start , read-row-done | 5.4.0 |
Index Reads | index-read-row-start ,
index-read-row-done | 5.4.0 |
Lock | handler-rdlock-start ,
handler-rdlock-done | 5.4.0 |
handler-wrlock-start ,
handler-wrlock-done | 5.4.0 | |
handler-unlock-start ,
handler-unlock-done | 5.4.0 | |
Filesort | filesort-start , filesort-done | 5.4.0 |
Statement | select-start , select-done | 5.4.0 |
insert-start , insert-done | 5.4.0 | |
insert-select-start ,
insert-select-done | 5.4.0 | |
update-start , update-done | 5.4.0 | |
multi-update-start ,
multi-update-done | 5.4.0 | |
delete-start , delete-done | 5.4.0 | |
multi-delete-start ,
multi-delete-done | 5.4.0 | |
Network | net-read-start , net-read-done ,
net-write-start ,
net-write-done | 5.4.0 |
Keycache | keycache-read-start ,
keycache-read-block ,
keycache-read-done ,
keycache-read-hit ,
keycache-read-miss ,
keycache-write-start ,
keycache-write-block ,
keycache-write-done | 5.4.0 |
When extracting the argument data from the probes, each argument
is available as
arg
, starting
with N
arg0
. To identify each argument within
the definitions they are provided with a descriptive name, but
you must access the information using the corresponding
arg
parameter.
N
The connection-start
and
connection-done
probes enclose a connection
from a client, regardless of whether the connection is through a
socket or network connection.
connection-start(connectionid, user, host) connection-done(status, connectionid)
connection-start
: Triggered after a
connection and successful login/authentication have been
completed by a client. The arguments contain the connection
information:
connectionid
: An unsigned
long
containing the connection ID. This is the
same as the process ID shown as the
Id
value in the output from
SHOW PROCESSLIST
.
user
: The username used when
authenticating. The value will be blank for the
anonymous user.
host
: The host of the client
connection. For a connection made using UNIX sockets,
the value will be blank.
connection-done
: Triggered just as the
connection to the client has been closed. The arguments are:
status
: The status of the connection
when it was closed. A logout operation will have a value
of 0; any other termination of the connection has a
nonzero value.
connectionid
: The connection ID of
the connection that was closed.
The following D script will quantify and summarize the average duration of individual connections, and provide a count, dumping the information every 60 seconds:
#!/usr/sbin/dtrace -s mysql*:::connection-start { self->start = timestamp; } mysql*:::connection-done /self->start/ { @ = quantize(((timestamp - self->start)/1000000)); self->start = 0; } tick-60s { printa(@); }
When executed on a server with a large number of clients you might see output similar to this:
1 57413 :tick-60s value ------------- Distribution ------------- count -1 | 0 0 |@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ 30011 1 | 59 2 | 5 4 | 20 8 | 29 16 | 18 32 | 27 64 | 30 128 | 11 256 | 10 512 | 1 1024 | 6 2048 | 8 4096 | 9 8192 | 8 16384 | 2 32768 | 1 65536 | 1 131072 | 0 262144 | 1 524288 | 0
The command probes are executed before and after a client
command is executed, including any SQL statement that might be
executed during that period. Commands include operations such as
the initialization of the DB, use of the
COM_CHANGE_USER
operation (supported by the
MySQL protocol), and manipulation of prepared statements. Many
of these commands are used only by the MySQL client API from
various connectors such as PHP and Java.
command-start(connectionid, command, user, host) command-done(status)
command-start
: Triggered when a command
is submitted to the server.
connectionid
: The connection ID of
the client executing the command.
command
: An integer representing the
command that was executed. Possible values are shown in
the following table.
Value | Name | Description |
---|---|---|
00 | COM_SLEEP | Internal thread state |
01 | COM_QUIT | Close connection |
02 | COM_INIT_DB | Select database (USE ... ) |
03 | COM_QUERY | Execute a query |
04 | COM_FIELD_LIST | Get a list of fields |
05 | COM_CREATE_DB | Create a database (deprecated) |
06 | COM_DROP_DB | Drop a database (deprecated) |
07 | COM_REFRESH | Refresh connection |
08 | COM_SHUTDOWN | Shutdown server |
09 | COM_STATISTICS | Get statistics |
10 | COM_PROCESS_INFO | Get processes (SHOW PROCESSLIST ) |
11 | COM_CONNECT | Initialize connection |
12 | COM_PROCESS_KILL | Kill process |
13 | COM_DEBUG | Get debug information |
14 | COM_PING | Ping |
15 | COM_TIME | Internal thread state |
16 | COM_DELAYED_INSERT | Internal thread state |
17 | COM_CHANGE_USER | Change user |
18 | COM_BINLOG_DUMP | Used by a replication slave or mysqlbinlog to initiate a binary log read |
19 | COM_TABLE_DUMP | Used by a replication slave to get the master table information |
20 | COM_CONNECT_OUT | Used by a replication slave to log a connection to the server |
21 | COM_REGISTER_SLAVE | Used by a replication slave during registration |
22 | COM_STMT_PREPARE | Prepare a statement |
23 | COM_STMT_EXECUTE | Execute a statement |
24 | COM_STMT_SEND_LONG_DATA | Used by a client when requesting extended data |
25 | COM_STMT_CLOSE | Close a prepared statement |
26 | COM_STMT_RESET | Reset a prepared statement |
27 | COM_SET_OPTION | Set a server option |
28 | COM_STMT_FETCH | Fetch a prepared statement |
user
: The user executing the command.
host
: The client host.
command-done
: Triggered when the command
execution completes. The status
argument
contains 0 if the command executed successfully, or 1 if the
statement was terminated before normal completion.
The command-start
and
command-done
probes are best used when
combined with the statement probes to get an idea of overall
execution time.
The query-start
and
query-done
probes are triggered when a
specific query is received by the server and when the query has
been completed and the information has been successfully sent to
the client.
query-start(query, connectionid, database, user, host) query-done(status)
query-start
: Triggered after the query
string has been received from the client. The arguments are:
query
: The full text of the submitted
query.
connectionid
: The connection ID of
the client that submitted the query. The connection ID
equals the connection ID returned when the client first
connects and the Id
value in the
output from SHOW
PROCESSLIST
.
database
: The database name on which
the query is being executed.
user
: The username used to connect to
the server.
host
: The hostname of the client.
query-done
: Triggered once the query has
been executed and the information has been returned to the
client. The probe includes a single argument,
status
, which returns 0 when the query is
successfully executed and 1 if there was an error.
You can get a simple report of the execution time for each query using the following D script:
#!/usr/sbin/dtrace -s #pragma D option quiet dtrace:::BEGIN { printf("%-20s %-20s %-40s %-9s\n", "Who", "Database", "Query", "Time(ms)"); } mysql*:::query-start { self->query = copyinstr(arg0); self->connid = arg1; self->db = copyinstr(arg2); self->who = strjoin(copyinstr(arg3),strjoin("@",copyinstr(arg4))); self->querystart = timestamp; } mysql*:::query-done { printf("%-20s %-20s %-40s %-9d\n",self->who,self->db,self->query, (timestamp - self->querystart) / 1000000); }
When executing the above script you should get a basic idea of the execution time of your queries:
shell> ./query.d Who Database Query Time(ms) root@localhost test select * from t1 order by i limit 10 0 root@localhost test set global query_cache_size=0 0 root@localhost test select * from t1 order by i limit 10 776 root@localhost test select * from t1 order by i limit 10 773 root@localhost test select * from t1 order by i desc limit 10 795
The query parsing probes are triggered before the original SQL statement is parsed and when the parsing of the statement and determination of the execution model required to process the statement has been completed:
query-parse-start(query) query-parse-done(status)
query-parse-start
: Triggered just before
the statement is parsed by the MySQL query parser. The
single argument, query
, is a string
containing the full text of the original query.
query-parse-done
: Triggered when the
parsing of the original statement has been completed. The
status
is an integer describing the
status of the operation. A 0
indicates
that the query was successfully parsed. A
1
indicates that the parsing of the query
failed.
For example, you could monitor the execution time for parsing a given query using the following D script:
#!/usr/sbin/dtrace -s #pragma D option quiet mysql*:::query-parse-start { self->parsestart = timestamp; self->parsequery = copyinstr(arg0); } mysql*:::query-parse-done /arg0 == 0/ { printf("Parsing %s: %d microseconds\n", self->parsequery,((timestamp - self->parsestart)/1000)); } mysql*:::query-parse-done /arg0 != 0/ { printf("Error parsing %s: %d microseconds\n", self->parsequery,((timestamp - self->parsestart)/1000)); }
In the above script a predicate is used on
query-parse-done
so that different output is
generated based on the status value of the probe.
When running the script and monitoring the execution:
shell> ./query-parsing.d Error parsing select from t1 join (t2) on (t1.i = t2.i) order by t1.s,t1.i limit 10: 36 ms Parsing select * from t1 join (t2) on (t1.i = t2.i) order by t1.s,t1.i limit 10: 176 ms
The query cache probes are fired when executing any query. The
query-cache-hit
query is triggered when a
query exists in the query cache and can be used to return the
query cache information. The arguments contain the original
query text and the number of rows returned from the query cache
for the query. If the query is not within the query cache, or
the query cache is not enabled, then the
query-cache-miss
probe is triggered instead.
query-cache-hit(query, rows) query-cache-miss(query)
query-cache-hit
: Triggered when the query
has been found within the query cache. The first argument,
query
, contains the original text of the
query. The second argument, rows
, is an
integer containing the number of rows in the cached query.
query-cache-miss
: Triggered when the
query is not found within the query cache. The first
argument, query
, contains the original
text of the query.
The query cache probes are best combined with a probe on the main query so that you can determine the differences in times between using or not using the query cache for specified queries. For example, in the following D script, the query and query cache information are combined into the information output during monitoring:
#!/usr/sbin/dtrace -s #pragma D option quiet dtrace:::BEGIN { printf("%-20s %-20s %-40s %2s %-9s\n", "Who", "Database", "Query", "QC", "Time(ms)"); } mysql*:::query-start { self->query = copyinstr(arg0); self->connid = arg1; self->db = copyinstr(arg2); self->who = strjoin(copyinstr(arg3),strjoin("@",copyinstr(arg4))); self->querystart = timestamp; self->qc = 0; } mysql*:::query-cache-hit { self->qc = 1; } mysql*:::query-cache-miss { self->qc = 0; } mysql*:::query-done { printf("%-20s %-20s %-40s %-2s %-9d\n",self->who,self->db,self->query,(self->qc ? "Y" : "N"), (timestamp - self->querystart) / 1000000); }
When executing the script you can see the effects of the query cache. Initially the query cache is disabled. If you set the query cache size and then execute the query multiple times you should see that the query cache is being used to return the query data:
shell> ./query-cache.d root@localhost test select * from t1 order by i limit 10 N 1072 root@localhost set global query_cache_size=262144 N 0 root@localhost test select * from t1 order by i limit 10 N 781 root@localhost test select * from t1 order by i limit 10 Y 0
The query execution probe is triggered when the actual execution of the query starts, after the parsing and checking the query cache but before any privilege checks or optimization. By comparing the difference between the start and done probes you can monitor the time actually spent servicing the query (instead of just handling the parsing and other elements of the query).
query-exec-start(query, connectionid, database, user, host, exec_type) query-exec-done(status)
The information provided in the arguments for
query-start
and
query-exec-start
are almost identical and
designed so that you can choose to monitor either the entire
query process (using query-start
) or only
the execution (using query-exec-start
)
while exposing the core information about the user, client,
and query being executed.
query-exec-start
: Triggered when the
execution of a individual query is started. The arguments
are:
query
: The full text of the submitted
query.
connectionid
: The connection ID of
the client that submitted the query. The connection ID
equals the connection ID returned when the client first
connects and the Id
value in the
output from SHOW
PROCESSLIST
.
database
: The database name on which
the query is being executed.
user
: The username used to connect to
the server.
host
: The hostname of the client.
exec_type
: The type of execution.
Execution types are determined based on the contents of
the query and where it was submitted. The values for
each type are shown in the following table.
Value | Description |
---|---|
0 | Executed query from sql_parse, top-level query. |
1 | Executed prepared statement |
2 | Executed cursor statement |
3 | Executed query in stored procedure |
query-exec-done
: Triggered when the
execution of the query has completed. The probe includes a
single argument, status
, which returns 0
when the query is successfully executed and 1 if there was
an error.
The *row-{start,done}
probes are triggered
each time a row operation is pushed down to a storage engine.
For example, if you execute an
INSERT
statement with 100 rows of
data, then the insert-row-start
and
insert-row-done
probes will be triggered 100
times each, for each row insert.
insert-row-start(database, table) insert-row-done(status) update-row-start(database, table) update-row-done(status) delete-row-start(database, table) delete-row-done(status)
insert-row-start
: Triggered before a row
is inserted into a table.
insert-row-done
: Triggered after a row is
inserted into a table.
update-row-start
: Triggered before a row
is updated in a table.
update-row-done
: Triggered before a row
is updated in a table.
delete-row-start
: Triggered before a row
is deleted from a table.
delete-row-done
: Triggered before a row
is deleted from a table.
The arguments supported by the probes are consistent for the
corresponding start
and
done
probes in each case:
database
: The database name.
table
: The table name.
status
: The status; 0 for success or 1
for failure.
Because the row-level probes are triggered for each individual
row access, these probes can be triggered many thousands of
times each second, which may have a detrimental effect on both
the monitoring script and MySQL. The DTrace environment should
limit the triggering on these probes to prevent the performance
being adversely affected. Either use the probes sparingly, or
use counter or aggregation functions to report on these probes
and then provide a summary when the script terminates or as part
of a query-done
or
query-exec-done
probes.
The following example script summarizes the duration of each row operation within a larger query:
#!/usr/sbin/dtrace -s #pragma D option quiet dtrace:::BEGIN { printf("%-2s %-10s %-10s %9s %9s %-s \n", "St", "Who", "DB", "ConnID", "Dur ms", "Query"); } mysql*:::query-start { self->query = copyinstr(arg0); self->who = strjoin(copyinstr(arg3),strjoin("@",copyinstr(arg4))); self->db = copyinstr(arg2); self->connid = arg1; self->querystart = timestamp; self->rowdur = 0; } mysql*:::query-done { this->elapsed = (timestamp - self->querystart) /1000000; printf("%2d %-10s %-10s %9d %9d %s\n", arg0, self->who, self->db, self->connid, this->elapsed, self->query); } mysql*:::query-done / self->rowdur / { printf("%34s %9d %s\n", "", (self->rowdur/1000000), "-> Row ops"); } mysql*:::insert-row-start { self->rowstart = timestamp; } mysql*:::delete-row-start { self->rowstart = timestamp; } mysql*:::update-row-start { self->rowstart = timestamp; } mysql*:::insert-row-done { self->rowdur += (timestamp-self->rowstart); } mysql*:::delete-row-done { self->rowdur += (timestamp-self->rowstart); } mysql*:::update-row-done { self->rowdur += (timestamp-self->rowstart); }
Running the above script with a query that inserts data into a table, you can monitor the exact time spent performing the raw row insertion:
St Who DB ConnID Dur ms Query 0 @localhost test 13 20767 insert into t1(select * from t2) 4827 -> Row ops
The read row probes are triggered at a storage engine level each
time a row read operation occurs. These probes are specified
within each storage engine (as opposed to the
*row-start
probes which are in the storage
engine interface). These probes can therefore be used to monitor
individual storage engine row-level operations and performance.
Because these probes are triggered around the storage engine row
read interface, they may be hit a significant number of times
during a basic query.
read-row-start(database, table, scan_flag) read-row-done(status)
read-row-start
: Triggered when a row is
read by the storage engine from the specified
database
and table
.
The scan_flag
is set to 1 (true) when the
read is part of a table scan (that is, a sequential read),
or 0 (false) when the read is of a specific record.
read-row-done
: Triggered when a row read
operation within a storage engine completes. The
status
returns 0 on success, or a
positive value on failure.
The index probes are triggered each time a a row is read using one of the indexes for the specified table. The probe is triggered within the corresponding storage engine for the table.
index-read-row-start(database, table) index-read-row-done(status)
index-read-row-start
: Triggered when a
row is read by the storage engine from the specified
database
and table
.
index-read-row-done
: Triggered when an
indexed row read operation within a storage engine
completes. The status
returns 0 on
success, or a positive value on failure.
The lock probes are called whenever an external lock is requested by MySQL for a table using the corresponding lock mechanism on the table as defined by the table's engine type. There are three different types of lock, the read lock, write lock, and unlock operations. Using the probes you can determine the duration of the external locking routine (that is, the time taken by the storage engine to implement the lock, including any time waiting for another lock to become free) and the total duration of the lock/unlock process.
handler-rdlock-start(database, table) handler-rdlock-done(status) handler-wrlock-start(database, table) handler-wrlock-done(status) handler-unlock-start(database, table) handler-unlock-done(status)
handler-rdlock-start
: Triggered when a
read lock is requested on the specified
database
and table
.
handler-wrlock-start
: Triggered when a
write lock is requested on the specified
database
and table
.
handler-unlock-start
: Triggered when an
unlock request is made on the specified
database
and table
.
handler-rdlock-done
: Triggered when a
read lock request completes. The status
is 0 if the lock operation succeeded, or
>0
on failure.
handler-wrlock-done
: Triggered when a
write lock request completes. The status
is 0 if the lock operation succeeded, or
>0
on failure.
handler-unlock-done
: Triggered when an
unlock request completes. The status
is 0
if the unlock operation succeeded, or
>0
on failure.
You can use arrays to monitor the locking and unlocking of individual tables and then calculate the duration of the entire table lock using the following script:
#!/usr/sbin/dtrace -s #pragma D option quiet mysql*:::handler-rdlock-start { self->rdlockstart = timestamp; this->lockref = strjoin(copyinstr(arg0),strjoin("@",copyinstr(arg1))); self->lockmap[this->lockref] = self->rdlockstart; printf("Start: Lock->Read %s.%s\n",copyinstr(arg0),copyinstr(arg1)); } mysql*:::handler-wrlock-start { self->wrlockstart = timestamp; this->lockref = strjoin(copyinstr(arg0),strjoin("@",copyinstr(arg1))); self->lockmap[this->lockref] = self->rdlockstart; printf("Start: Lock->Write %s.%s\n",copyinstr(arg0),copyinstr(arg1)); } mysql*:::handler-unlock-start { self->unlockstart = timestamp; this->lockref = strjoin(copyinstr(arg0),strjoin("@",copyinstr(arg1))); printf("Start: Lock->Unlock %s.%s (%d ms lock duration)\n", copyinstr(arg0),copyinstr(arg1), (timestamp - self->lockmap[this->lockref])/1000000); } mysql*:::handler-rdlock-done { printf("End: Lock->Read %d ms\n", (timestamp - self->rdlockstart)/1000000); } mysql*:::handler-wrlock-done { printf("End: Lock->Write %d ms\n", (timestamp - self->wrlockstart)/1000000); } mysql*:::handler-unlock-done { printf("End: Lock->Unlock %d ms\n", (timestamp - self->unlockstart)/1000000); }
When executed, you should get information both about the duration of the locking process itself, and of the locks on a specific table:
Start: Lock->Read test.t2 End: Lock->Read 0 ms Start: Lock->Unlock test.t2 (25743 ms lock duration) End: Lock->Unlock 0 ms Start: Lock->Read test.t2 End: Lock->Read 0 ms Start: Lock->Unlock test.t2 (1 ms lock duration) End: Lock->Unlock 0 ms Start: Lock->Read test.t2 End: Lock->Read 0 ms Start: Lock->Unlock test.t2 (1 ms lock duration) End: Lock->Unlock 0 ms Start: Lock->Read test.t2 End: Lock->Read 0 ms
The filesort probes are triggered whenever a filesort operation
is applied to a table. For more information on filesort and the
conditions under which it occurs, see
Section 8.13.12, “ORDER BY
Optimization”.
filesort-start(database, table) filesort-done(status, rows)
filesort-start
: Triggered when the
filesort operation starts on a table. The two arguments to
the probe, database
and
table
, will identify the table being
sorted.
filesort-done
: Triggered when the
filesort operation completes. Two arguments are supplied,
the status
(0 for success, 1 for
failure), and the number of rows sorted during the filesort
process.
An example of this is in the following script, which tracks the duration of the filesort process in addition to the duration of the main query:
#!/usr/sbin/dtrace -s #pragma D option quiet dtrace:::BEGIN { printf("%-2s %-10s %-10s %9s %18s %-s \n", "St", "Who", "DB", "ConnID", "Dur microsec", "Query"); } mysql*:::query-start { self->query = copyinstr(arg0); self->who = strjoin(copyinstr(arg3),strjoin("@",copyinstr(arg4))); self->db = copyinstr(arg2); self->connid = arg1; self->querystart = timestamp; self->filesort = 0; self->fsdb = ""; self->fstable = ""; } mysql*:::filesort-start { self->filesort = timestamp; self->fsdb = copyinstr(arg0); self->fstable = copyinstr(arg1); } mysql*:::filesort-done { this->elapsed = (timestamp - self->filesort) /1000; printf("%2d %-10s %-10s %9d %18d Filesort on %s\n", arg0, self->who, self->fsdb, self->connid, this->elapsed, self->fstable); } mysql*:::query-done { this->elapsed = (timestamp - self->querystart) /1000; printf("%2d %-10s %-10s %9d %18d %s\n", arg0, self->who, self->db, self->connid, this->elapsed, self->query); }
Executing a query on a large table with an ORDER
BY
clause that triggers a filesort, and then creating
an index on the table and then repeating the same query, you can
see the difference in execution speed:
St Who DB ConnID Dur microsec Query 0 @localhost test 14 11335469 Filesort on t1 0 @localhost test 14 11335787 select * from t1 order by i limit 100 0 @localhost test 14 466734378 create index t1a on t1 (i) 0 @localhost test 14 26472 select * from t1 order by i limit 100
The individual statement probes are provided to give specific
information about different statement types. For the start
probes the string of the query is provided as a the only
argument. Depending on the statement type, the information
provided by the corresponding done probe will differ. For all
done probes the status of the operation (0
for success, >0
for failure) is provided.
For SELECT
,
INSERT
,
INSERT ... (SELECT FROM
...)
, DELETE
, and
DELETE FROM
t1,t2
operations the number of rows affected is
returned.
For UPDATE
and
UPDATE t1,t2
...
statements the number of rows matched and the
number of rows actually changed is provided. This is because the
number of rows actually matched by the corresponding
WHERE
clause, and the number of rows changed
can differ. MySQL does not update the value of a row if the
value already matches the new setting.
select-start(query) select-done(status,rows) insert-start(query) insert-done(status,rows) insert-select-start(query) insert-select-done(status,rows) update-start(query) update-done(status,rowsmatched,rowschanged) multi-update-start(query) multi-update-done(status,rowsmatched,rowschanged) delete-start(query) delete-done(status,rows) multi-delete-start(query) multi-delete-done(status,rows)
select-start
: Triggered before a
SELECT
statement.
select-done
: Triggered at the end of a
SELECT
statement.
insert-start
: Triggered before a
INSERT
statement.
insert-done
: Triggered at the end of an
INSERT
statement.
insert-select-start
: Triggered before an
INSERT ...
SELECT
statement.
insert-select-done
: Triggered at the end
of an INSERT ...
SELECT
statement.
update-start
: Triggered before an
UPDATE
statement.
update-done
: Triggered at the end of an
UPDATE
statement.
multi-update-start
: Triggered before an
UPDATE
statement involving
multiple tables.
multi-update-done
: Triggered at the end
of an UPDATE
statement
involving multiple tables.
delete-start
: Triggered before a
DELETE
statement.
delete-done
: Triggered at the end of a
DELETE
statement.
multi-delete-start
: Triggered before a
DELETE
statement involving
multiple tables.
multi-delete-done
: Triggered at the end
of a DELETE
statement
involving multiple tables.
The arguments for the statement probes are:
query
: The query string.
status
: The status of the query.
0
for success, and
>0
for failure.
rows
: The number of rows affected by the
statement. This returns the number rows found for
SELECT
, the number of rows
deleted for DELETE
, and the
number of rows successfully inserted for
INSERT
.
rowsmatched
: The number of rows matched
by the WHERE
clause of an
UPDATE
operation.
rowschanged
: The number of rows actually
changed during an UPDATE
operation.
You use these probes to monitor the execution of these statement types without having to monitor the user or client executing the statements. A simple example of this is to track the execution times:
#!/usr/sbin/dtrace -s #pragma D option quiet dtrace:::BEGIN { printf("%-60s %-8s %-8s %-8s\n", "Query", "RowsU", "RowsM", "Dur (ms)"); } mysql*:::update-start, mysql*:::insert-start, mysql*:::delete-start, mysql*:::multi-delete-start, mysql*:::multi-delete-done, mysql*:::select-start, mysql*:::insert-select-start, mysql*:::multi-update-start { self->query = copyinstr(arg0); self->querystart = timestamp; } mysql*:::insert-done, mysql*:::select-done, mysql*:::delete-done, mysql*:::multi-delete-done, mysql*:::insert-select-done / self->querystart / { this->elapsed = ((timestamp - self->querystart)/1000000); printf("%-60s %-8d %-8d %d\n", self->query, 0, arg1, this->elapsed); self->querystart = 0; } mysql*:::update-done, mysql*:::multi-update-done / self->querystart / { this->elapsed = ((timestamp - self->querystart)/1000000); printf("%-60s %-8d %-8d %d\n", self->query, arg1, arg2, this->elapsed); self->querystart = 0; }
When executed you can see the basic execution times and rows matches:
Query RowsU RowsM Dur (ms) select * from t2 0 275 0 insert into t2 (select * from t2) 0 275 9 update t2 set i=5 where i > 75 110 110 8 update t2 set i=5 where i < 25 254 134 12 delete from t2 where i < 5 0 0 0
Another alternative is to use the aggregation functions in DTrace to aggregate the execution time of individual statements together:
#!/usr/sbin/dtrace -s #pragma D option quiet mysql*:::update-start, mysql*:::insert-start, mysql*:::delete-start, mysql*:::multi-delete-start, mysql*:::multi-delete-done, mysql*:::select-start, mysql*:::insert-select-start, mysql*:::multi-update-start { self->querystart = timestamp; } mysql*:::select-done { @statements["select"] = sum(((timestamp - self->querystart)/1000000)); } mysql*:::insert-done, mysql*:::insert-select-done { @statements["insert"] = sum(((timestamp - self->querystart)/1000000)); } mysql*:::update-done, mysql*:::multi-update-done { @statements["update"] = sum(((timestamp - self->querystart)/1000000)); } mysql*:::delete-done, mysql*:::multi-delete-done { @statements["delete"] = sum(((timestamp - self->querystart)/1000000)); } tick-30s { printa(@statements); }
The script just shown aggregates the times spent doing each operation, which could be used to help benchmark a standard suite of tests.
delete 0 update 0 insert 23 select 2484 delete 0 update 0 insert 39 select 10744 delete 0 update 26 insert 56 select 10944 delete 0 update 26 insert 2287 select 15985
The network probes monitor the transfer of information from the MySQL server and clients of all types over the network. The probes are defined as follows:
net-read-start() net-read-done(status, bytes) net-write-start(bytes) net-write-done(status)
net-read-start
: Triggered when a network
read operation is started.
net-read-done
: Triggered when the network
read operation completes. The status
is
an integer
representing the return status
for the operation, 0
for success and
1
for failure. The
bytes
argument is an integer specifying
the number of bytes read during the process.
net-start-bytes
: Triggered when data is
written to a network socket. The single argument,
bytes
, specifies the number of bytes
written to the network socket.
net-write-done
: Triggered when the
network write operation has completed. The single argument,
status
, is an integer representing the
return status for the operation, 0
for
success and 1
for failure.
You can use the network probes to monitor the time spent reading
from and writing to network clients during execution. The
following D script provides an example of this. Both the
cumulative time for the read or write is calculated, and the
number of bytes. Note that the dynamic variable size has been
increased (using the dynvarsize
option) to
cope with the rapid firing of the individual probes for the
network reads/writes.
#!/usr/sbin/dtrace -s #pragma D option quiet #pragma D option dynvarsize=4m dtrace:::BEGIN { printf("%-2s %-30s %-10s %9s %18s %-s \n", "St", "Who", "DB", "ConnID", "Dur microsec", "Query"); } mysql*:::query-start { self->query = copyinstr(arg0); self->who = strjoin(copyinstr(arg3),strjoin("@",copyinstr(arg4))); self->db = copyinstr(arg2); self->connid = arg1; self->querystart = timestamp; self->netwrite = 0; self->netwritecum = 0; self->netwritebase = 0; self->netread = 0; self->netreadcum = 0; self->netreadbase = 0; } mysql*:::net-write-start { self->netwrite += arg0; self->netwritebase = timestamp; } mysql*:::net-write-done { self->netwritecum += (timestamp - self->netwritebase); self->netwritebase = 0; } mysql*:::net-read-start { self->netreadbase = timestamp; } mysql*:::net-read-done { self->netread += arg1; self->netreadcum += (timestamp - self->netreadbase); self->netreadbase = 0; } mysql*:::query-done { this->elapsed = (timestamp - self->querystart) /1000000; printf("%2d %-30s %-10s %9d %18d %s\n", arg0, self->who, self->db, self->connid, this->elapsed, self->query); printf("Net read: %d bytes (%d ms) write: %d bytes (%d ms)\n", self->netread, (self->netreadcum/1000000), self->netwrite, (self->netwritecum/1000000)); }
When executing the above script on a machine with a remote client, you can see that approximately a third of the time spent executing the query is related to writing the query results back to the client.
St Who DB ConnID Dur microsec Query 0 root@::ffff:192.168.0.108 test 31 3495 select * from t1 limit 1000000 Net read: 0 bytes (0 ms) write: 10000075 bytes (1220 ms)
The keycache probes are triggered when using the index key cache used with the MyISAM storage engine. Probes exist to monitor when data is read into the keycache, cached key data is written from the cache into a cached file, or when accessing the keycache.
Keycache usage indicates when data is read or written from the index files into the cache, and can be used to monitor how efficient the memory allocated to the keycache is being used. A high number of keycache reads across a range of queries may indicate that the keycache is too small for size of data being accessed.
keycache-read-start(filepath, bytes, mem_used, mem_free) keycache-read-block(bytes) keycache-read-hit() keycache-read-miss() keycache-read-done(mem_used, mem_free) keycache-write-start(filepath, bytes, mem_used, mem_free) keycache-write-block(bytes) keycache-write-done(mem_used, mem_free)
When reading data from the index files into the keycache, the
process first initializes the read operation (indicated by
keycache-read-start
), then loads blocks of
data (keycache-read-block
), and then the read
block is either matches the data being identified
(keycache-read-hit
) or more data needs to be
read (keycache-read-miss
). Once the read
operation has completed, reading stops with the
keycache-read-done
.
Data will be read from the index file into the keycache only when the specified key is not already within the keycache.
keycache-read-start
: Triggered when the
keycache read operation is started. Data is read from the
specified filepath
, reading the specified
number of bytes
. The
mem_used
and mem_avail
indicate memory currently used by the keycache and the
amount of memory available within the keycache.
keycache-read-block
: Triggered when the
keycache reads a block of data, of the specified number of
bytes
, from the index file into the
keycache.
keycache-read-hit
: Triggered when the
block of data read from the index file matches the key data
requested.
keycache-read-miss
: Triggered when the
block of data read from the index file does not match the
key data needed.
keycache-read-done
: Triggered when the
keycache read operation has completed. The
mem_used
and mem_avail
indicate memory currently used by the keycache and the
amount of memory available within the keycache.
Keycache writes occur when the index information is updated
during an INSERT
, UPDATE
,
or DELETE
operation, and the cached key
information is flushed back to the index file.
keycache-write-start
: Triggered when the
keycache write operation is started. Data is written to the
specified filepath
, reading the specified
number of bytes
. The
mem_used
and mem_avail
indicate memory currently used by the keycache and the
amount of memory available within the keycache.
keycache-write-block
: Triggered when the
keycache writes a block of data, of the specified number of
bytes
, to the index file from the
keycache.
keycache-write-done
: Triggered when the
keycache write operation has completed. The
mem_used
and mem_avail
indicate memory currently used by the keycache and the
amount of memory available within the keycache.