The mysqldump Database Backup Program

The mysqldump client can be used to dump a database or a collection of databases for backup or for transferring the data to another SQL server (not necessarily a MySQL server). The dump will contain SQL statements to create the table and/or populate the table.

If you are doing a backup on the server, you should consider using the mysqlhotcopy instead. See mysqlhotcopy.

There are three general ways to invoke mysqldump:

shell> mysqldump [options] db_name [tables]
shell> mysqldump [options] --databases DB1 [DB2 DB3...]
shell> mysqldump [options] --all-databases

If you don't name any tables or use the --databases or --all-databases option, entire databases will be dumped.

To get a list of the options your version of mysqldump supports, execute mysqldump --help.

If you run mysqldump without the --quick or --opt option, mysqldump will load the whole result set into memory before dumping the result. This will probably be a problem if you are dumping a big database. As of MySQL 4.1, --opt is on by default, but can be disabled with --skip-opt.

If you are using a recent copy of the mysqldump program and you are going to generate a dump that will be reloaded into a very old MySQL server, you should not use the --opt or -e options.

Out-of-range numeric values such as -inf and inf, as well as NaN (not-a-number) values are dumped by mysqldump as NULL. You can see this using the following sample table:

mysql> CREATE TABLE t (f DOUBLE);
mysql> INSERT INTO t VALUES(1e+111111111111111111111);
mysql> INSERT INTO t VALUES(-1e111111111111111111111);
mysql> SELECT f FROM t;
+------+
| f    |
+------+
|  inf |
| -inf |
+------+

For this table, mysqldump produces the following data output:

--
-- Dumping data for table `t`
--

INSERT INTO t VALUES (NULL);
INSERT INTO t VALUES (NULL);

The significance of this behavior is that if you dump and restore the table, the new table has contents that differ from the original contents. Note that since MySQL 4.1.2 you cannot insert inf in the table, so this mysqldump behavior is only relevant when you deal with old servers.

mysqldump supports the following options:

--help, -?

Display a help message and exit.

--add-drop-table

Add a DROP TABLE statement before each CREATE TABLE statement.

--add-locks

Surround each table dump with LOCK TABLES and UNLOCK TABLES statements. This results in faster inserts when the dump file is reloaded. See the section called “Speed of INSERT Statements”.

--all-databases, -A

Dump all tables in all databases. This is the same as using the --databases option and naming all the databases on the command line.

--allow-keywords

Allow creation of column names that are keywords. This works by prefixing each column name with the table name.

--comments[={0|1}]

If set to 0, suppresses additional information in the dump file such as program version, server version, and host. --skip-comments has the same effect as --comments=0. The default value is 1 to not suppress the extra information. New in MySQL 4.0.17.

--compatible=name

Produce output that is compatible with other database systems or with older MySQL servers. The value of name can be ansi, mysql323, mysql40, postgresql, oracle, mssql, db2, maxdb, no_key_options, no_table_options, or no_field_options. To use several values, separate them by commas. These values have the same meaning as the corresponding options for setting the server SQL mode. See the section called “The Server SQL Mode”.

This option requires a server version of 4.1.0 or higher. With older servers, it does nothing.

--complete-insert, -c

Use complete INSERT statements that include column names.

--compress, -C

Compress all information sent between the client and the server if both support compression.

--create-options

Include all MySQL-specific table options in the CREATE TABLE statements. Before MySQL 4.1.2, use --all instead.

--databases, -B

To dump several databases. Note the difference in usage. In this case, no tables are given. All name arguments on the command line are regarded as database names. A USE db_name statement is included in the output before each new database.

--debug[=debug_options], -# [debug_options]

Write a debugging log. The debug_options string often is 'd:t:o,file_name'.

--default-character-set=charset

Use charset as the default character set. See the section called “The Character Set Used for Data and Sorting”. If not specified, mysqldump from MySQL 4.1.2 or later uses utf8; earlier versions use latin1.

--delayed

Insert rows using INSERT DELAYED statements.

--delete-master-logs

On a master replication server, delete the binary logs after performing the dump operation. This option automatically enables --first-slave. It was added in MySQL 3.23.57 (for MySQL 3.23) and MySQL 4.0.13 (for MySQL 4.0).

--disable-keys, -K

For each table, surround the INSERT statements with /*!40000 ALTER TABLE tbl_name DISABLE KEYS */; and /*!40000 ALTER TABLE tbl_name ENABLE KEYS */; statements. This makes loading the dump file into a MySQL 4.0 server faster because the indexes are created after all rows are inserted. This option is effective only for MyISAM tables.

--extended-insert, -e

Use multiple-row INSERT syntax that include several VALUES lists. This results in a smaller dump file and speeds up inserts when the file is reloaded.

--fields-terminated-by=..., --fields-enclosed-by=..., --fields-optionally-enclosed-by=..., --fields-escaped-by=..., --lines-terminated-by=...,

These options are used with the -T option and have the same meaning as the corresponding clauses for LOAD DATA INFILE. See LOAD DATA.

--first-slave, -x

Locks all tables across all databases.

--flush-logs, -F

Flush the MySQL server log files before starting the dump. Note that if you use this option in combination with the --all-databases (or -A) option, the logs are flushed for each database dumped.

--force, -f

Continue even if an SQL error occurs during a table dump.

--host=host_name, -h host_name

Dump data from the MySQL server on the given host. The default host is localhost.

--lock-tables, -l

Lock all tables before starting the dump. The tables are locked with READ LOCAL to allow concurrent inserts in the case of MyISAM tables.

Please note that when dumping multiple databases, --lock-tables locks tables for each database separately. So, using this option will not guarantee that the tables in the dump file will be logically consistent between databases. Tables in different databases may be dumped in completely different states.

--master-data

This option is like --first-slave, but also produces CHANGE MASTER TO statements that will make your slave server start from the correct position in the master's binary logs if you use this SQL dump of the master to set up the slave.

--no-create-db, -n

This option suppresses the CREATE DATABASE /*!32312 IF NOT EXISTS*/ db_name statements that are otherwise included in the output if the --databases or --all-databases option is given.

--no-create-info, -t

Don't write CREATE TABLE statements that re-create each dumped table.

--no-data, -d

Don't write any row information for the table. This is very useful if you just want to get a dump of the structure for a table.

--opt

This option is shorthand; it is the same as specifying --add-drop-table --add-locks --create-options --disable-keys --extended-insert --lock-tables --quick --set-charset. It should give you a fast dump operation and produce a dump file that can be reloaded into a MySQL server quickly. As of MySQL 4.1, --opt is on by default, but can be disabled with --skip-opt. To disable only certain of the options enabled by --opt, use their --skip forms; for example, --skip-add-drop-table or --skip-quick.

--password[=password], -p[password]

The password to use when connecting to the server. If you use the short option form (-p), you cannot have a space between the option and the password. If no password is given on the command line, you will be prompted for one.

--port=port_num, -P port_num

The TCP/IP port number to use for the connection.

--protocol={TCP | SOCKET | PIPE | MEMORY}

The connection protocol to use. New in MySQL 4.1.

--quick, -q

This option is useful for dumping large tables. It forces mysqldump to retrieve rows for a table from the server a row at a time rather than retrieving the entire row set and buffering it in memory before writing it out.

--quote-names, -Q

Quote database, table, and column names within ‘`’ characters. If the server SQL mode includes the ANSI_QUOTES option, names are quoted within ‘"’ characters. As of MySQL 4.1.1, --quote-names is on by default, but can be disabled with --skip-quote-names.

--result-file=file, -r file

Direct output to a given file. This option should be used on Windows, because it prevents newline ‘\n’ characters from being converted to ‘\r\n’ carriage return/newline sequences.

--set-charset

Add SET NAMES default_character_set to the output. This option is enabled by default. To suppress the SET NAMES statement, use --skip-set-charset. This option was added in MySQL 4.1.2.

--single-transaction

This option issues a BEGIN SQL statement before dumping data from the server. It is mostly useful with InnoDB tables and READ COMMITTED transaction isolation level, because in this mode it will dump the consistent state of the database at the time then BEGIN was issued without blocking any applications.

When using this option, you should keep in mind that only transactional tables will be dumped in a consistent state. For example, any MyISAM or HEAP tables dumped while using this option may still change state.

The --single-transaction option was added in MySQL 4.0.2. This option is mutually exclusive with the --lock-tables option, because LOCK TABLES causes any pending transactions to be committed implicitly.

--socket=path, -S path

The socket file to use when connecting to localhost (which is the default host).

--skip-comments

See the description for the --comments option.

--tab=path, -T path

Produces tab-separated data files. For each dumped table, mysqldump creates a tbl_name.sql file that contains the CREATE TABLE statement that creates the table, and a tbl_name.txt file that contains its data. The option value is the directory in which to write the files.

By default, the .txt data files are formatted using tab characters between column values and a newline at the end of each line. The format can be specified explicitly using the --fields-xxx and --lines--xxx options.

Note: This option should be used only when mysqldump is run on the same machine as the mysqld server. You must use a MySQL account that has the FILE privilege, and the server must have permission to write files in the directory you specify.

--tables

Overrides the --databases or -B option. All arguments following the option are regarded as table names.

--user=user_name, -u user_name

The MySQL username to use when connecting to the server.

--verbose, -v

Verbose mode. Print out more information on what the program does.

--version, -V

Display version information and exit.

--where='where-condition', -w 'where-condition'

Dump only records selected by the given WHERE condition. Note that quotes around the condition are mandatory if it contains spaces or characters that are special to your command interpreter.

Examples:

"--where=user='jimf'"
"-wuserid>1"
"-wuserid<1"
--xml, -X

Write dump output as well-formed XML.

You can also set the following variables by using --var_name=value options:

max_allowed_packet

The maximum size of the buffer for client/server communication. The value of the variable can be up to 16MB before MySQL 4.0, and up to 1GB from MySQL 4.0 on. When creating multiple-row-insert statements (as with option --extended-insert or --opt), mysqldump will create rows up to max_allowed_packet length. If you increase this variable, you should also ensure that the max_allowed_packet variable in the MySQL server is at least this large.

net_buffer_length

The initial size of the buffer for client/server communication.

It is also possible to set variables by using --set-variable=var_name=value or -O var_name=value syntax. However, this syntax is deprecated as of MySQL 4.0.

The most common use of mysqldump is probably for making a backup of entire databases.

shell> mysqldump --opt db_name > backup-file.sql

You can read the dump file back into the server with:

shell> mysql db_name < backup-file.sql

Or:

shell> mysql -e "source /path-to-backup/backup-file.sql" db_name

mysqldump is also very useful for populating databases by copying data from one MySQL server to another:

shell> mysqldump --opt db_name | mysql --host=remote_host -C db_name

It is possible to dump several databases with one command:

shell> mysqldump --databases db_name1 [db_name2 ...] > my_databases.sql

If you want to dump all databases, use the --all-databases option:

shell> mysqldump --all-databases > all_databases.sql

For more information on making backups, see the section called “Database Backups”.