4.5.4 mysqldump — A Database Backup Program

The mysqldump client is a backup program originally written by Igor Romanenko. It can be used to dump a database or a collection of databases for backup or transfer to another SQL server (not necessarily a MySQL server). The dump typically contains SQL statements to create the table, populate it, or both. However, mysqldump can also be used to generate files in CSV, other delimited text, or XML format.

mysqldump requires at least the SELECT privilege for dumped tables, SHOW VIEW for dumped views, TRIGGER for dumped triggers, and LOCK TABLES if the --single-transaction option is not used. Certain options might require other privileges as noted in the option descriptions.

To reload a dump file, you must have the same privileges needed to create each of the dumped objects by issuing CREATE statements manually.

mysqldump output can include ALTER DATABASE statements that change the database collation. These may be used when dumping stored programs to preserve their character encodings. To reload a dump file containing such statements, the ALTER privilege for the affected database is required.

If you are performing a backup on the server and your tables all are MyISAM tables, you can also use mysqlhotcopy for this purpose.

Syntax

There are in general three ways to use mysqldump—in order to dump a set of one or more tables, a set of one or more complete databases, or an entire MySQL server—as shown here:

shell> mysqldump [options] db_name [tbl_name ...]
shell> mysqldump [options] --databases db_name ...
shell> mysqldump [options] --all-databases

To dump entire databases, do not name any tables following db_name, or use the --databases or --all-databases option.

mysqldump does not dump the INFORMATION_SCHEMA database by default. As of MySQL 5.1.38, mysqldump dumps INFORMATION_SCHEMA if you name it explicitly on the command line, although you must also use the --skip-lock-tables option. Before 5.1.38, mysqldump silently ignores INFORMATION_SCHEMA even if you name it explicitly on the command line.

Before MySQL 5.1.64, mysqldump does not dump the general_log or slow_query_log tables for dumps of the mysql database. As of 5.1.64, 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.

In MySQL Cluster NDB 7.1.7 and later, the ndbinfo information database is ignored and not dumped by mysqldump.

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

Some mysqldump options are shorthand for groups of other options:

To reverse the effect of a group option, uses its --skip-xxx form (--skip-opt or --skip-compact). It is also possible to select only part of the effect of a group option by following it with options that enable or disable specific features. Here are some examples:

When you selectively enable or disable the effect of a group option, order is important because options are processed first to last. For example, --disable-keys --lock-tables --skip-opt would not have the intended effect; it is the same as --skip-opt by itself.

mysqldump can retrieve and dump table contents row by row, or it can retrieve the entire content from a table and buffer it in memory before dumping it. Buffering in memory can be a problem if you are dumping large tables. To dump tables row by row, use the --quick option (or --opt, which enables --quick). The --opt option (and hence --quick) is enabled by default, so to enable memory buffering, use --skip-quick.

If you are using a recent version of mysqldump to generate a dump to be reloaded into a very old MySQL server, you should not use the --opt or --extended-insert option. Use --skip-opt instead.

Note

mysqldump from MySQL 5.1.21 cannot be used to create dumps from MySQL server 5.1.20 and older. This issue is fixed in MySQL 5.1.22. (Bug #30123)

mysqldump supports the following options, which can be specified on the command line or in the [mysqldump] and [client] groups of an option file. For information about option files used by MySQL programs, see Section 4.2.6, “Using Option Files”.

Table 4.5 mysqldump Options

FormatDescriptionIntroduced
--add-drop-databaseAdd a DROP DATABASE statement before each CREATE DATABASE statement 
--add-drop-tableAdd a DROP TABLE statement before each CREATE TABLE statement 
--add-drop-triggerAdd a DROP TRIGGER statement before each CREATE TRIGGER statement5.1.47-ndb-7.1.8
--add-locksSurround each table dump with LOCK TABLES and UNLOCK TABLES statements 
--all-databasesDump all tables in all databases 
--all-tablespacesAdds to a table dump all SQL statements needed to create any tablespaces used by an NDB Cluster table5.1.6
--allow-keywordsAllow creation of column names that are keywords 
--bind-address=ip_addressUse specified network interface to connect to MySQL Server5.1.22-ndb-6.3.4
--commentsAdd comments to the dump file 
--compactProduce more compact output 
--compatible=name[,name,...]Produce output that is more compatible with other database systems or with older MySQL servers 
--complete-insertUse complete INSERT statements that include column names 
--create-optionsInclude all MySQL-specific table options in CREATE TABLE statements 
--databasesDump several databases 
--debug[=debug_options]Write a debugging log 
--debug-checkPrint debugging information when program exits5.1.21
--debug-infoPrint debugging information, memory, and CPU statistics when program exits5.1.14
--default-character-set=charset_nameSpecify default character set 
--defaults-extra-file=file_nameRead option file in addition to usual option files 
--defaults-file=file_nameRead only named option file 
--defaults-group-suffix=strOption group suffix value 
--delayed-insertWrite INSERT DELAYED statements rather than INSERT statements 
--delete-master-logsOn a master replication server, delete the binary logs after performing the dump operation 
--disable-keysFor each table, surround the INSERT statements with statements to disable and enable keys 
--dump-dateInclude dump date as "Dump completed on" comment if --comments is given5.1.23
--eventsDump events from the dumped databases5.1.8
--extended-insertUse multiple-row INSERT syntax that include several VALUES lists 
--fields-enclosed-by=stringThis option is used with the --tab option and has the same meaning as the corresponding clause for LOAD DATA INFILE 
--fields-escaped-byThis option is used with the --tab option and has the same meaning as the corresponding clause for LOAD DATA INFILE 
--fields-optionally-enclosed-by=stringThis option is used with the --tab option and has the same meaning as the corresponding clause for LOAD DATA INFILE 
--fields-terminated-by=stringThis option is used with the --tab option and has the same meaning as the corresponding clause for LOAD DATA INFILE 
--first-slaveDeprecated; use --lock-all-tables instead 
--flush-logsFlush the MySQL server log files before starting the dump 
--flush-privilegesEmit a FLUSH PRIVILEGES statement after dumping the mysql database 
--helpDisplay help message and exit 
--hex-blobDump binary columns using hexadecimal notation (for example, 'abc' becomes 0x616263) 
--hostHost to connect to (IP address or hostname) 
--ignore-table=db_name.tbl_nameDo not dump the given table 
--insert-ignoreWrite INSERT IGNORE statements rather than INSERT statements 
--lines-terminated-by=stringThis option is used with the --tab option and has the same meaning as the corresponding clause for LOAD DATA INFILE 
--lock-all-tablesLock all tables across all databases 
--lock-tablesLock all tables before dumping them 
--log-error=file_nameAppend warnings and errors to the named file5.1.18
--master-data[=value]Write the binary log file name and position to the output 
--max_allowed_packet=valueMaximum packet length to send to or receive from server 
--net_buffer_length=valueBuffer size for TCP/IP and socket communication 
--no-autocommitEnclose the INSERT statements for each dumped table within SET autocommit = 0 and COMMIT statements 
--no-create-dbThis option suppresses the CREATE DATABASE statements 
--no-create-infoDo not write CREATE TABLE statements that re-create each dumped table 
--no-dataDo not dump table contents 
--no-defaultsRead no option files 
--no-set-namesSame as --skip-set-charset 
--no-tablespacesDo not write any CREATE LOGFILE GROUP or CREATE TABLESPACE statements in output5.1.14
--optShorthand for --add-drop-table --add-locks --create-options --disable-keys --extended-insert --lock-tables --quick --set-charset. 
--order-by-primaryDump each table's rows sorted by its primary key, or by its first unique index 
--password[=password]Password to use when connecting to server 
--pipeOn Windows, connect to server using named pipe 
--port=port_numTCP/IP port number to use for connection 
--print-defaultsPrint defaults 
--protocol=typeConnection protocol to use 
--quickRetrieve rows for a table from the server a row at a time 
--quote-namesQuote identifiers within backtick characters 
--replaceWrite REPLACE statements rather than INSERT statements5.1.3
--result-file=fileDirect output to a given file 
--routinesDump stored routines (procedures and functions) from the dumped databases5.1.2
--set-charsetAdd SET NAMES default_character_set to output 
--shared-memory-base-name=nameThe name of shared memory to use for shared-memory connections 
--single-transactionThis option issues a BEGIN SQL statement before dumping data from the server 
--skip-add-drop-tableDo not add a DROP TABLE statement before each CREATE TABLE statement 
--skip-add-locksDo not add locks 
--skip-commentsDo not add comments to the dump file 
--skip-compactDo not produce more compact output 
--skip-disable-keysDo not disable keys 
--skip-extended-insertTurn off extended-insert 
--skip-optTurn off the options set by --opt 
--skip-quickDo not retrieve rows for a table from the server a row at a time 
--skip-quote-namesDo not quote identifiers 
--skip-set-charsetSuppress the SET NAMES statement 
--skip-triggersDo not dump triggers 
--skip-tz-utcTurn off tz-utc5.1.2
--socket=pathFor connections to localhost, the Unix socket file to use 
--sslEnable SSL for connection 
--ssl-ca=file_namePath of file that contains list of trusted SSL CAs 
--ssl-capath=dir_namePath of directory that contains trusted SSL CA certificates in PEM format 
--ssl-cert=file_namePath of file that contains X509 certificate in PEM format 
--ssl-cipher=cipher_listList of permitted ciphers to use for SSL encryption 
--ssl-key=file_namePath of file that contains X509 key in PEM format 
--ssl-verify-server-certVerify server Common Name value in its certificate against host name used when connecting to server5.1.11
--tab=pathProduce tab-separated data files 
--tablesOverride the --databases or -B option 
--triggersDump triggers for each dumped table 
--tz-utcAdd SET TIME_ZONE='+00:00' to the dump file5.1.2
--user=user_nameMySQL user name to use when connecting to server 
--verboseVerbose mode 
--versionDisplay version information and exit 
--where='where_condition'Dump only rows selected by the given WHERE condition 
--xmlProduce XML output 

Prior to MySQL 5.1.62, this option prevented the --routines option from working correctly—that is, no stored routines, triggers, or events could be dumped in XML format. (Bug #11760384, Bug #52792)

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

A common use of mysqldump is for making a backup of an entire database:

shell> mysqldump db_name > backup-file.sql

You can load the dump file back into the server like this:

shell> mysql db_name < backup-file.sql

Or like this:

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

To dump all databases, use the --all-databases option:

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

For InnoDB tables, mysqldump provides a way of making an online backup:

shell> mysqldump --all-databases --master-data --single-transaction > all_databases.sql

This backup acquires a global read lock on all tables (using FLUSH TABLES WITH READ LOCK) at the beginning of the dump. As soon as this lock has been acquired, the binary log coordinates are read and the lock is released. If long updating statements are running when the FLUSH statement is issued, the MySQL server may get stalled until those statements finish. After that, the dump becomes lock free and does not disturb reads and writes on the tables. If the update statements that the MySQL server receives are short (in terms of execution time), the initial lock period should not be noticeable, even with many updates.

For point-in-time recovery (also known as roll-forward, when you need to restore an old backup and replay the changes that happened since that backup), it is often useful to rotate the binary log (see Section 5.2.4, “The Binary Log”) or at least know the binary log coordinates to which the dump corresponds:

shell> mysqldump --all-databases --master-data=2 > all_databases.sql

Or:

shell> mysqldump --all-databases --flush-logs --master-data=2
              > all_databases.sql

The --master-data and --single-transaction options can be used simultaneously, which provides a convenient way to make an online backup suitable for use prior to point-in-time recovery if tables are stored using the InnoDB storage engine.

For more information on making backups, see Section 7.2, “Database Backup Methods”, and Section 7.3, “Example Backup and Recovery Strategy”.

If you encounter problems backing up views, please read the section that covers restrictions on views which describes a workaround for backing up views when this fails due to insufficient privileges. See Section D.4, “Restrictions on Views”.