Chapter 5. Database Administration

Table of Contents

5.1. The MySQL Server and Server Startup Scripts
5.1.5.1.1. Overview of the Server-Side Scripts and Utilities
5.1.5.1.2. The mysqld-max Extended MySQL Server
5.1.5.1.3. The mysqld_safe Server Startup Script
5.1.5.1.4. The mysql.server Server Startup Script
5.1.5.1.5. The mysqld_multi Program for Managing Multiple MySQL Servers
5.2. Configuring the MySQL Server
5.2.5.2.1. mysqld Command-Line Options
5.2.5.2.2. The Server SQL Mode
5.2.5.2.3. Server System Variables
5.2.5.2.4. Server Status Variables
5.3. The MySQL Server Shutdown Process
5.4. General Security Issues
5.4.5.4.1. General Security Guidelines
5.4.5.4.2. Making MySQL Secure Against Attackers
5.4.5.4.3. Startup Options for mysqld Concerning Security
5.4.5.4.4. Security Issues with LOAD DATA LOCAL
5.5. The MySQL Access Privilege System
5.5.5.5.1. What the Privilege System Does
5.5.5.5.2. How the Privilege System Works
5.5.5.5.3. Privileges Provided by MySQL
5.5.5.5.4. Connecting to the MySQL Server
5.5.5.5.5. Access Control, Stage 1: Connection Verification
5.5.5.5.6. Access Control, Stage 2: Request Verification
5.5.5.5.7. When Privilege Changes Take Effect
5.5.5.5.8. Causes of Access denied Errors
5.5.5.5.9. Password Hashing in MySQL 4.1
5.6. MySQL User Account Management
5.6.5.6.1. MySQL Usernames and Passwords
5.6.5.6.2. Adding New User Accounts to MySQL
5.6.5.6.3. Removing User Accounts from MySQL
5.6.5.6.4. Limiting Account Resources
5.6.5.6.5. Assigning Account Passwords
5.6.5.6.6. Keeping Your Password Secure
5.6.5.6.7. Using Secure Connections
5.7. Disaster Prevention and Recovery
5.7.5.7.1. Database Backups
5.7.5.7.2. Table Maintenance and Crash Recovery
5.7.5.7.3. Setting Up a Table Maintenance Schedule
5.7.5.7.4. Getting Information About a Table
5.8. MySQL Localization and International Usage
5.8.5.8.1. The Character Set Used for Data and Sorting
5.8.5.8.2. Setting the Error Message Language
5.8.5.8.3. Adding a New Character Set
5.8.5.8.4. The Character Definition Arrays
5.8.5.8.5. String Collating Support
5.8.5.8.6. Multi-Byte Character Support
5.8.5.8.7. Problems With Character Sets
5.8.5.8.8. MySQL Server Time Zone Support
5.9. The MySQL Log Files
5.9.5.9.1. The Error Log
5.9.5.9.2. The General Query Log
5.9.5.9.3. The Update Log
5.9.5.9.4. The Binary Log
5.9.5.9.5. The Slow Query Log
5.9.5.9.6. Log File Maintenance
5.10. Running Multiple MySQL Servers on the Same Machine
5.10.5.10.1. Running Multiple Servers on Windows
5.10.5.10.2. Running Multiple Servers on Unix
5.10.5.10.3. Using Client Programs in a Multiple-Server Environment
5.11. The MySQL Query Cache
5.11.5.11.1. How the Query Cache Operates
5.11.5.11.2. Query Cache SELECT Options
5.11.5.11.3. Query Cache Configuration
5.11.5.11.4. Query Cache Status and Maintenance

This chapter covers topics that deal with administering a MySQL installation, such as configuring the server, managing user accounts, and performing backups.

The MySQL Server and Server Startup Scripts

The MySQL server, mysqld, is the main program that does most of the work in a MySQL installation. The server is accompanied by several related scripts that perform setup operations when you install MySQL or that are helper programs to assist you in starting and stopping the server.

This section provides an overview of the server and related programs, and information about server startup scripts. Information about configuring the server itself is given in the section called “Configuring the MySQL Server”.

Overview of the Server-Side Scripts and Utilities

All MySQL programs take many different options. However, every MySQL program provides a --help option that you can use to get a description of the program's options. For example, try mysqld --help.

You can override default options for all standard programs by specifying options on the command line or in an option file. the section called “Specifying Program Options”.

The following list briefly describes the MySQL server and server-related programs:

mysqld

The SQL daemon (that is, the MySQL server). To use client programs, this program must be running, because clients gain access to databases by connecting to the server. See the section called “Configuring the MySQL Server”.

mysqld-max

A version of the server that includes additional features. See mysqld-max.

mysqld_safe

A server startup script. mysqld_safe attempts to start mysqld-max if it exists, and mysqld otherwise. See mysqld_safe.

mysql.server

A server startup script. This script is used on systems that use run directories containing scripts that start system services for particular run levels. It invokes mysqld_safe to start the MySQL server. See mysql.server.

mysqld_multi

A server startup script that can start or stop multiple servers installed on the system. See mysqld_multi.

mysql_install_db

This script creates the MySQL grant tables with default privileges. It is usually executed only once, when first installing MySQL on a system.

mysql_fix_privilege_tables

This script is used after an upgrade install operation, to update the grant tables with any changes that have been made in newer versions of MySQL.

There are several other programs that also are run on the server host:

myisamchk

A utility to describe, check, optimize, and repair MyISAM tables. myisamchk is described in the section called “Table Maintenance and Crash Recovery”.

make_binary_distribution

This program makes a binary release of a compiled MySQL. This could be sent by FTP to /pub/mysql/upload/ on ftp.mysql.com for the convenience of other MySQL users.

mysqlbug

The MySQL bug reporting script. It can be used to send a bug report to the MySQL mailing list. (You can also visit http://bugs.mysql.com/ to file a bug report online.)

The mysqld-max Extended MySQL Server

A MySQL-Max server is a version of the mysqld MySQL server that has been built to include additional features.

The distribution to use depends on your platform:

  • For Windows, MySQL binary distributions include both the standard server (mysqld.exe) and the MySQL-Max server (mysqld-max.exe), so you need not get a special distribution. Just use a regular Windows distribution, available at http://dev.mysql.com/downloads/mysql-4.0.html. See the section called “Installing MySQL on Windows”.

  • For Linux, if you install MySQL using RPM distributions, use the regular MySQL-server RPM first to install a standard server named mysqld. Then use the MySQL-Max RPM to install a server named mysqld-max. The MySQL-Max RPM presupposes that you have already installed the regular server RPM. See the section called “Installing MySQL on Linux” for more information on the Linux RPM packages.

  • All other MySQL-Max distributions contain a single server that is named mysqld but that has the additional features included.

You can find the MySQL-Max binaries on the MySQL AB Web site at http://dev.mysql.com/downloads/mysql-4.0.html.

MySQL AB builds the MySQL-Max servers by using the following configure options:

--with-server-suffix=-max

This option adds a -max suffix to the mysqld version string.

--with-innodb

This option enables support for the InnoDB storage engine. MySQL-Max servers always include InnoDB support, but this option actually is needed only for MySQL 3.23. From MySQL 4 on, InnoDB is included by default in binary distributions, so you do not need a MySQL-Max server to obtain InnoDB support.

--with-bdb

This option enables support for the Berkeley DB (BDB) storage engine.

CFLAGS=-DUSE_SYMDIR

This define enables symbolic link support for Windows.

MySQL-Max binary distributions are a convenience for those who wish to install precompiled programs. If you build MySQL using a source distribution, you can build your own Max-like server by enabling the same features at configuration time that the MySQL-Max binary distributions are built with.

MySQL-Max servers include the BerkeleyDB (BDB) storage engine whenever possible, but not all platforms support BDB. The following table shows which platforms allow MySQL-Max binaries to include BDB:

SystemBDBSupport
AIX 4.3N
HP-UX 11.0N
Linux-AlphaN
Linux-IA-64N
Linux-IntelY
Mac OS XN
NetWareN
SCO OSR5Y
Solaris-IntelN
Solaris-SPARCY
UnixWareY
Windows/NTY

To find out which storage engines your server supports, issue the following statement:

mysql> SHOW ENGINES;

Before MySQL 4.1.2, SHOW ENGINES is unavailable. Use the following statement instead and check the value of the variable for the storage engine in which you are interested:

mysql> SHOW VARIABLES LIKE 'have_%';
+------------------+----------+
| Variable_name    | Value    |
+------------------+----------+
| have_bdb         | NO       |
| have_crypt       | YES      |
| have_innodb      | YES      |
| have_isam        | NO       |
| have_raid        | NO       |
| have_symlink     | DISABLED |
| have_openssl     | NO       |
| have_query_cache | YES      |
+------------------+----------+

The values in the second column indicate the server's level of support for each feature:

ValueMeaning
YESThe feature is supported and is active.
NOThe feature is not supported.
DISABLEDThe feature is supported but has been disabled.

A value of NO means that the server was compiled without support for the feature, so it cannot be activated at runtime.

A value of DISABLED occurs either because the server was started with an option that disables the feature, or because not all options required to enable it were given. In the latter case, the host_name.err error log file should contain a reason indicating why the option is disabled.

One situation in which you might see DISABLED occurs with MySQL 3.23 when the InnoDB storage engine is compiled in. In MySQL 3.23, you must supply at least the innodb_data_file_path option at runtime to set up the InnoDB tablespace. Without this option, InnoDB disables itself. See InnoDB in MySQL 3.23. You can specify configuration options for the BDB storage engine, too, but BDB will not disable itself if you do not provide them. See BDB start.

You might also see DISABLED for the InnoDB, BDB, or ISAM storage engines if the server was compiled to support them, but was started with the --skip-innodb, --skip-bdb, or --skip-isam options at runtime.

As of Version 3.23, all MySQL servers support MyISAM tables, because MyISAM is the default storage engine.

The mysqld_safe Server Startup Script

mysqld_safe is the recommended way to start a mysqld server on Unix and NetWare. mysqld_safe adds some safety features such as restarting the server when an error occurs and logging runtime information to an error log file. NetWare-specific behaviors are listed later in this section.

Note: Before MySQL 4.0, mysqld_safe is named safe_mysqld. To preserve backward compatibility, MySQL binary distributions for some time will include safe_mysqld as a symbolic link to mysqld_safe.

By default, mysqld_safe tries to start an executable named mysqld-max if it exists, or mysqld otherwise. Be aware of the implications of this behavior:

  • On Linux, the MySQL-Max RPM relies on this mysqld_safe behavior. The RPM installs an executable named mysqld-max, which causes mysqld_safe to automatically use that executable from that point on.

  • If you install a MySQL-Max distribution that includes a server named mysqld-max, then upgrade later to a non-Max version of MySQL, mysqld_safe will still attempt to run the old mysqld-max server. If you perform such an upgrade, you should manually remove the old mysqld-max server to ensure that mysqld_safe runs the new mysqld server.

To override the default behavior and specify explicitly which server you want to run, specify a --mysqld or --mysqld-version option to mysqld_safe.

Many of the options to mysqld_safe are the same as the options to mysqld. See the section called “mysqld Command-Line Options”.

All options specified to mysqld_safe on the command line are passed to mysqld. If you want to use any options that are specific to mysqld_safe and that mysqld doesn't support, do not specify them on the command line. Instead, list them in the [mysqld_safe] group of an option file. See the section called “Using Option Files”.

mysqld_safe reads all options from the [mysqld], [server], and [mysqld_safe] sections in option files. For backward compatibility, it also reads [safe_mysqld] sections, although you should rename such sections to [mysqld_safe] when you begin using MySQL 4.0 or later.

mysqld_safe supports the following options:

--basedir=path

The path to the MySQL installation directory.

--core-file-size=size

The size of the core file mysqld should be able to create. The option value is passed to ulimit -c.

--datadir=path

The path to the data directory.

--defaults-extra-file=path

The name of an option file to be read in addition to the usual option files.

--defaults-file=path

The name of an option file to be read instead of the usual option files.

--err-log=path

The old form of the --log-error option, to be used before MySQL 4.0.

--ledir=path

The path to the directory containing the mysqld program. Use this option to explicitly indicate the location of the server.

--log-error=path

Write the error log to the given file. See the section called “The Error Log”.

--mysqld=prog_name

The name of the server program (in the ledir directory) that you want to start. This option is needed if you use the MySQL binary distribution but have the data directory outside of the binary distribution.

--mysqld-version=suffix

This option is similar to the --mysqld option, but you specify only the suffix for the server program name. The basename is assumed to be mysqld. For example, if you use --mysqld-version=max, mysqld_safe will start the mysqld-max program in the ledir directory. If the argument to --mysqld-version is empty, mysqld_safe uses mysqld in the ledir directory.

--nice=priority

Use the nice program to set the server's scheduling priority to the given value. This option was added in MySQL 4.0.14.

--no-defaults

Do not read any option files.

--open-files-limit=count

The number of files mysqld should be able to open. The option value is passed to ulimit -n. Note that you need to start mysqld_safe as root for this to work properly!

--pid-file=path

The path to the process ID file.

--port=port_num

The port number to use when listening for TCP/IP connections.

--socket=path

The Unix socket file to use for local connections.

--timezone=zone

Set the TZ time zone environment variable to the given option value. Consult your operating system documentation for legal time zone specification formats.

--user={user_name | user_id}

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.)

The mysqld_safe script is written so that it normally can start a server that was installed from either a source or a binary distribution of MySQL, even though these types of distributions typically install the server in slightly different locations. (See the section called “Installation Layouts”.) mysqld_safe expects one of the following conditions to be true:

  • The server and databases can be found relative to the directory from which mysqld_safe is invoked. For binary distributions, mysqld_safe looks under its working directory for bin and data directories. For source distributions, it looks for libexec and var directories. This condition should be met if you execute mysqld_safe from your MySQL installation directory (for example, /usr/local/mysql for a binary distribution).

  • If the server and databases cannot be found relative to the working directory, mysqld_safe attempts to locate them by absolute pathnames. Typical locations are /usr/local/libexec and /usr/local/var. The actual locations are determined from the values configured into the distribution at the time it was built. They should be correct if MySQL is installed in the location specified at configuration time.

Because mysqld_safe will try to find the server and databases relative to its own working directory, you can install a binary distribution of MySQL anywhere, as long as you run mysqld_safe from the MySQL installation directory:

shell> cd mysql_installation_directory
shell> bin/mysqld_safe &

If mysqld_safe fails, even when invoked from the MySQL installation directory, you can specify the --ledir and --datadir options to indicate the directories in which the server and databases are located on your system.

Normally, you should not edit the mysqld_safe script. Instead, configure mysqld_safe by using command-line options or options in the [mysqld_safe] section of a my.cnf option file. In rare cases, it might be necessary to edit mysqld_safe to get it to start the server properly. However, if you do this, your modified version of mysqld_safe might be overwritten if you upgrade MySQL in the future, so you should make a copy of your edited version that you can reinstall.

On NetWare, mysqld_safe is a NetWare Loadable Module (NLM) that is ported from the original Unix shell script. It does the following:

  1. Runs a number of system and option checks.

  2. Runs a check on MyISAM and ISAM tables.

  3. Provides a screen presence for the MySQL server.

  4. Starts mysqld, monitors it, and restarts it if it terminates in error.

  5. Sends error messages from mysqld to the host_name.err file in the data directory.

  6. Sends mysqld_safe screen output to the host_name.safe file in the data directory.

The mysql.server Server Startup Script

MySQL distributions on Unix include a script named mysql.server. It can be used on systems such as Linux and Solaris that use System V-style run directories to start and stop system services. It is also used by the Mac OS X Startup Item for MySQL.

mysql.server can be found in the support-files directory under your MySQL installation directory or in a MySQL source tree.

If you use the Linux server RPM package (MySQL-server-VERSION.rpm), the mysql.server script will already have been installed in the /etc/init.d directory with the name mysql. You need not install it manually. See the section called “Installing MySQL on Linux” for more information on the Linux RPM packages.

Some vendors provide RPM packages that install a startup script under a different name such as mysqld.

If you install MySQL from a source distribution or using a binary distribution format that does not install mysql.server automatically, you can install it manually. Instructions are provided in the section called “Starting and Stopping MySQL Automatically”.

mysql.server reads options from the [mysql.server] and [mysqld] sections of option files. (For backward compatibility, it also reads [mysql_server] sections, although you should rename such sections to [mysql.server] when you begin using MySQL 4.0 or later.)

The mysqld_multi Program for Managing Multiple MySQL Servers

mysqld_multi is meant for managing several mysqld processes that listen for connections on different Unix socket files and TCP/IP ports. It can start or stop servers, or report their current status.

The program searches for groups named [mysqld#] in my.cnf (or in the file named by the --config-file option). # can be any positive integer. This number is referred to in the following discussion as the option group number, or GNR. Group numbers distinguish option groups from one another and are used as arguments to mysqld_multi to specify which servers you want to start, stop, or obtain a status report for. Options listed in these groups are the same that you would use in the [mysqld] group used for starting mysqld. (See, for example, the section called “Starting and Stopping MySQL Automatically”.) However, when using multiple servers it is necessary that each one use its own value for options such as the Unix socket file and TCP/IP port number. For more information on which options must be unique per server in a multiple-server environment, see the section called “Running Multiple MySQL Servers on the Same Machine”.

To invoke mysqld_multi, use the following syntax:

shell> mysqld_multi [options] {start|stop|report} [GNR[,GNR]...]

start, stop, and report indicate which operation you want to perform. You can perform the designated operation on a single server or multiple servers, depending on the GNR list that follows the option name. If there is no list, mysqld_multi performs the operation for all servers in the option file.

Each GNR value represents an option group number or range of group numbers. The value should be the number at the end of the group name in the option file. For example, the GNR for a group named [mysqld17] is 17. To specify a range of numbers, separate the first and last numbers by a dash. The GNR value 10-13 represents groups [mysqld10] through [mysqld13]. Multiple groups or group ranges can be specified on the command line, separated by commas. There must be no whitespace characters (spaces or tabs) in the GNR list; anything after a whitespace character is ignored.

This command starts a single server using option group [mysqld17]:

shell> mysqld_multi start 17

This command stops several servers, using option groups [mysql8] and [mysqld10] through [mysqld13]:

shell> mysqld_multi stop 8,10-13

For an example of how you might set up an option file, use this command:

shell> mysqld_multi --example

mysqld_multi supports the following options:

--config-file=name

Specify the name of an alternative option file. This affects where mysqld_multi looks for [mysqld#] option groups. Without this option, all options are read from the usual my.cnf file. The option does not affect where mysqld_multi reads its own options, which are always taken from the [mysqld_multi] group in the usual my.cnf file.

--example

Display a sample option file.

--help

Display a help message and exit.

--log=name

Specify the name of the log file. If the file exists, log output is appended to it.

--mysqladmin=prog_name

The mysqladmin binary to be used to stop servers.

--mysqld=prog_name

The mysqld binary to be used. Note that you can specify mysqld_safe as the value for this option also. The options are passed to mysqld. Just make sure that you have the directory where mysqld is located in your PATH environment variable setting or fix mysqld_safe.

--no-log

Print log information to stdout rather than to the log file. By default, output goes to the log file.

--password=password

The password of the MySQL account to use when invoking mysqladmin. Note that the password value is not optional for this option, unlike for other MySQL programs.

--tcp-ip

Connect to each MySQL server via the TCP/IP port instead of the Unix socket file. (If a socket file is missing, the server might still be running, but accessible only via the TCP/IP port.) By default, connections are made using the Unix socket file. This option affects stop and report operations.

--user=user_name

The username of the MySQL account to use when invoking mysqladmin.

--version

Display version information and exit.

Some notes about mysqld_multi:

  • Make sure that the MySQL account used for stopping the mysqld servers (with the mysqladmin program) has the same username and password for each server. Also, make sure that the account has the SHUTDOWN privilege. If the servers that you want to manage have many different usernames or passwords for the administrative accounts, you might want to create an account on each server that has the same username and password. For example, you might set up a common multi_admin account by executing the following commands for each server:

    shell> mysql -u root -S /tmp/mysql.sock -proot_password
    mysql> GRANT SHUTDOWN ON *.*
        -> TO 'multi_admin'@'localhost' IDENTIFIED BY 'multipass';
    

    See the section called “How the Privilege System Works”. You will have to do this for each mysqld server. Change the connection parameters appropriately when connecting to each one. Note that the host part of the account name must allow you to connect as multi_admin from the host where you want to run mysqld_multi.

  • The --pid-file option is very important if you are using mysqld_safe to start mysqld (for example, --mysqld=mysqld_safe) Every mysqld should have its own process ID file. The advantage of using mysqld_safe instead of mysqld is that mysqld_safe “guards” its mysqld process and will restart it if the process terminates due to a signal sent using kill -9, or for other reasons, such as a segmentation fault. Please note that the mysqld_safe script might require that you start it from a certain place. This means that you might have to change location to a certain directory before running mysqld_multi. If you have problems starting, please see the mysqld_safe script. Check especially the lines:

    ----------------------------------------------------------------
    MY_PWD=`pwd`
    # Check if we are starting this relative (for the binary release)
    if test -d $MY_PWD/data/mysql -a -f ./share/mysql/english/errmsg.sys -a \
     -x ./bin/mysqld
    ----------------------------------------------------------------
    

    See mysqld_safe. The test performed by these lines should be successful, or you might encounter problems.

  • The Unix socket file and the TCP/IP port number must be different for every mysqld.

  • You might want to use the --user option for mysqld, but in order to do this you need to run the mysqld_multi script as the Unix root user. Having the option in the option file doesn't matter; you will just get a warning, if you are not the superuser and the mysqld processes are started under your own Unix account.

  • Important: Make sure that the data directory is fully accessible to the Unix account that the specific mysqld process is started as. Do not use the Unix root account for this, unless you know what you are doing.

  • Most important: Before using mysqld_multi be sure that you understand the meanings of the options that are passed to the mysqld servers and why you would want to have separate mysqld processes. Beware of the dangers of using multiple mysqld servers with the same data directory. Use separate data directories, unless you know what you are doing. Starting multiple servers with the same data directory will not give you extra performance in a threaded system. See the section called “Running Multiple MySQL Servers on the Same Machine”.

The following example shows how you might set up an option file for use with mysqld_multi. The first and fifth [mysqld#] group were intentionally left out from the example to illustrate that you can have “gaps” in the option file. This gives you more flexibility. The order in which the mysqld programs are started or stopped depends on the order in which they appear in the option file.

# This file should probably be in your home dir (~/.my.cnf)
# or /etc/my.cnf
# Version 2.1 by Jani Tolonen

[mysqld_multi]
mysqld     = /usr/local/bin/mysqld_safe
mysqladmin = /usr/local/bin/mysqladmin
user       = multi_admin
password   = multipass

[mysqld2]
socket     = /tmp/mysql.sock2
port       = 3307
pid-file   = /usr/local/mysql/var2/hostname.pid2
datadir    = /usr/local/mysql/var2
language   = /usr/local/share/mysql/english
user       = john

[mysqld3]
socket     = /tmp/mysql.sock3
port       = 3308
pid-file   = /usr/local/mysql/var3/hostname.pid3
datadir    = /usr/local/mysql/var3
language   = /usr/local/share/mysql/swedish
user       = monty

[mysqld4]
socket     = /tmp/mysql.sock4
port       = 3309
pid-file   = /usr/local/mysql/var4/hostname.pid4
datadir    = /usr/local/mysql/var4
language   = /usr/local/share/mysql/estonia
user       = tonu

[mysqld6]
socket     = /tmp/mysql.sock6
port       = 3311
pid-file   = /usr/local/mysql/var6/hostname.pid6
datadir    = /usr/local/mysql/var6
language   = /usr/local/share/mysql/japanese
user       = jani

See the section called “Using Option Files”.