6.5.4 mysqldump — A Database Backup Program (original) (raw)

6.5.4 mysqldump — A Database Backup Program

The mysqldump client utility performslogical backups, producing a set of SQL statements that can be executed to reproduce the original database object definitions and table data. It dumps one or more MySQL databases for backup or transfer to another SQL server. The mysqldump command can also generate output in CSV, other delimited text, or XML format.

Tip

Consider using the MySQL Shell dump utilities, which provide parallel dumping with multiple threads, file compression, and progress information display, as well as cloud features such as Oracle Cloud Infrastructure Object Storage streaming, and MySQL HeatWave Service compatibility checks and modifications. Dumps can be easily imported into a MySQL Server instance or a MySQL HeatWave Service DB System using the MySQL Shell load dump utilities. Installation instructions for MySQL Shell can be found here.

mysqldump requires at least theSELECT privilege for dumped tables, SHOW VIEW for dumped views, TRIGGER for dumped triggers, LOCK TABLES if the--single-transaction option is not used, PROCESS if the--no-tablespaces option is not used, and theRELOAD orFLUSH_TABLES privilege with--single-transaction if both gtid_mode=ON and gtid_purged=ON|AUTO. Certain options might require other privileges as noted in the option descriptions.

To reload a dump file, you must have the privileges required to execute the statements that it contains, such as the appropriateCREATE privileges for objects created by those statements.

mysqldump output can includeALTER 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, theALTER privilege for the affected database is required.

Note

A dump made using PowerShell on Windows with output redirection creates a file that has UTF-16 encoding:

mysqldump [options] > dump.sql

However, UTF-16 is not permitted as a connection character set (seeImpermissible Client Character Sets), so the dump file cannot be loaded correctly. To work around this issue, use the --result-file option, which creates the output in ASCII format:

mysqldump [options] --result-file=dump.sql

It is not recommended to load a dump file when GTIDs are enabled on the server (gtid_mode=ON), if your dump file includes system tables.mysqldump issues DML instructions for the system tables which use the non-transactional MyISAM storage engine, and this combination is not permitted when GTIDs are enabled.

Performance and Scalability Considerations

mysqldump advantages include the convenience and flexibility of viewing or even editing the output before restoring. You can clone databases for development and DBA work, or produce slight variations of an existing database for testing. It is not intended as a fast or scalable solution for backing up substantial amounts of data. With large data sizes, even if the backup step takes a reasonable time, restoring the data can be very slow because replaying the SQL statements involves disk I/O for insertion, index creation, and so on.

For large-scale backup and restore, aphysical backup is more appropriate, to copy the data files in their original format so that they can be restored quickly.

If your tables are primarily InnoDB tables, or if you have a mix of InnoDB andMyISAM tables, consider usingmysqlbackup, which is available as part of MySQL Enterprise. This tool provides high performance forInnoDB backups with minimal disruption; it can also back up tables from MyISAM and other storage engines; it also provides a number of convenient options to accommodate different backup scenarios. SeeSection 32.1, “MySQL Enterprise Backup Overview”.

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 ofmysqldump to generate a dump to be reloaded into a very old MySQL server, use the--skip-opt option instead of the --opt or--extended-insert option.

For additional information about mysqldump, see Section 9.4, “Using mysqldump for Backups”.

Invocation Syntax

There are in general three ways to usemysqldump—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:

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

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

To see a list of the options your version ofmysqldump supports, issue the commandmysqldump --help.

Option Syntax - Alphabetical Summary

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 6.2.2.2, “Using Option Files”.

Connection Options

The mysqldump command logs into a MySQL server to extract information. The following options specify how to connect to the MySQL server, either on the same machine or a remote system.

Option-File Options

These options are used to control which option files to read.

DDL Options

Usage scenarios for mysqldump include setting up an entire new MySQL instance (including database tables), and replacing data inside an existing instance with existing databases and tables. The following options let you specify which things to tear down and set up when restoring a dump, by encoding various DDL statements within the dump file.

Debug Options

The following options print debugging information, encode debugging information in the dump file, or let the dump operation proceed regardless of potential problems.

-- Dump completed on DATE  

However, the date causes dump files taken at different times to appear to be different, even if the data are otherwise identical. --dump-date and--skip-dump-date control whether the date is added to the comment. The default is --dump-date (include the date in the comment).--skip-dump-date suppresses date printing.

Help Options

The following options display information about themysqldump command itself.

Internationalization Options

The following options change how themysqldump command represents character data with national language settings.

Replication Options

The mysqldump command is frequently used to create an empty instance, or an instance including data, on a replica server in a replication configuration. The following options apply to dumping and restoring data on replication source servers and replicas.

Format Options

The following options specify how to represent the entire dump file or certain kinds of data in the dump file. They also control whether certain optional information is written to the dump file.

$> mysqldump --xml -u root world City  
<?xml version="1.0"?>  
<mysqldump xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance">  
<database name="world">  
<table_structure name="City">  
<field Field="ID" Type="int(11)" Null="NO" Key="PRI" Extra="auto_increment" />  
<field Field="Name" Type="char(35)" Null="NO" Key="" Default="" Extra="" />  
<field Field="CountryCode" Type="char(3)" Null="NO" Key="" Default="" Extra="" />  
<field Field="District" Type="char(20)" Null="NO" Key="" Default="" Extra="" />  
<field Field="Population" Type="int(11)" Null="NO" Key="" Default="0" Extra="" />  
<key Table="City" Non_unique="0" Key_name="PRIMARY" Seq_in_index="1" Column_name="ID"  
Collation="A" Cardinality="4079" Null="" Index_type="BTREE" Comment="" />  
<options Name="City" Engine="MyISAM" Version="10" Row_format="Fixed" Rows="4079"  
Avg_row_length="67" Data_length="273293" Max_data_length="18858823439613951"  
Index_length="43008" Data_free="0" Auto_increment="4080"  
Create_time="2007-03-31 01:47:01" Update_time="2007-03-31 01:47:02"  
Collation="latin1_swedish_ci" Create_options="" Comment="" />  
</table_structure>  
<table_data name="City">  
<row>  
<field name="ID">1</field>  
<field name="Name">Kabul</field>  
<field name="CountryCode">AFG</field>  
<field name="District">Kabol</field>  
<field name="Population">1780000</field>  
</row>  
...  
<row>  
<field name="ID">4079</field>  
<field name="Name">Rafah</field>  
<field name="CountryCode">PSE</field>  
<field name="District">Rafah</field>  
<field name="Population">92020</field>  
</row>  
</table_data>  
</database>  
</mysqldump>  

Filtering Options

The following options control which kinds of schema objects are written to the dump file: by category, such as triggers or events; by name, for example, choosing which databases and tables to dump; or even filtering rows from the table data using a WHERE clause.

--where="user='jimf'"  
-w"userid>1"  
-w"userid<1"  

Performance Options

The following options are the most relevant for the performance particularly of the restore operations. For large data sets, restore operation (processing the INSERT statements in the dump file) is the most time-consuming part. When it is urgent to restore data quickly, plan and test the performance of this stage in advance. For restore times measured in hours, you might prefer an alternative backup and restore solution, such asMySQL Enterprise Backup forInnoDB-only and mixed-use databases.

Performance is also affected by thetransactional options, primarily for the dump operation.

Transactional Options

The following options trade off the performance of the dump operation, against the reliability and consistency of the exported data.

Option Groups

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.

Examples

To make a backup of an entire database:

mysqldump db_name > backup-file.sql

To load the dump file back into the server:

mysql db_name < backup-file.sql

Another way to reload the dump file:

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:

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

You can dump several databases with one command:

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

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

mysqldump --all-databases > all_databases.sql

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

mysqldump --all-databases --source-data --single-transaction > all_databases.sql

This backup acquires a global read lock on all tables (usingFLUSH 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 theFLUSH 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 (seeSection 7.4.4, “The Binary Log”) or at least know the binary log coordinates to which the dump corresponds:

mysqldump --all-databases --source-data=2 > all_databases.sql

Or:

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

The --source-data option can be used simultaneously with the--single-transaction option, 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, seeSection 9.2, “Database Backup Methods”, andSection 9.3, “Example Backup and Recovery Strategy”.

Restrictions

mysqldump does not dump theperformance_schema or sys schema by default. To dump any of these, name them explicitly on the command line. You can also name them with the--databases option. Forperformance_schema, also use the--skip-lock-tables option.

mysqldump does not dump theINFORMATION_SCHEMA schema.

mysqldump does not dumpInnoDB CREATE TABLESPACE statements.

mysqldump does not dump the NDB Clusterndbinfo information database.

mysqldump includes statements to recreate thegeneral_log andslow_query_log tables for dumps of themysql database. Log table contents are not dumped.

If you encounter problems backing up views due to insufficient privileges, see Section 27.9, “Restrictions on Views” for a workaround.