1MYSQLDUMP(1)                 MySQL Database System                MYSQLDUMP(1)
2
3
4

NAME

6       mysqldump - a database backup program
7

SYNOPSIS

9       mysqldump [options] [db_name [tbl_name ...]]
10

DESCRIPTION

12       The mysqldump client utility performs logical backups, producing a set
13       of SQL statements that can be executed to reproduce the original
14       database object definitions and table data. It dumps one or more MySQL
15       databases for backup or transfer to another SQL server. The mysqldump
16       command can also generate output in CSV, other delimited text, or XML
17       format.
18
19           Tip
20           Consider using the MySQL Shell dump utilities[1], which provide
21           parallel dumping with multiple threads, file compression, and
22           progress information display, as well as cloud features such as
23           Oracle Cloud Infrastructure Object Storage streaming, and MySQL
24           Database Service compatibility checks and modifications. Dumps can
25           be easily imported into a MySQL Server instance or a MySQL Database
26           Service DB System using the MySQL Shell load dump utilities[2].
27           Installation instructions for MySQL Shell can be found here[3].
28
29       ·   Performance and Scalability Considerations
30
31       ·   Invocation Syntax
32
33       ·   Option Syntax - Alphabetical Summary
34
35       ·   Connection Options
36
37       ·   Option-File Options
38
39       ·   DDL Options
40
41       ·   Debug Options
42
43       ·   Help Options
44
45       ·   Internationalization Options
46
47       ·   Replication Options
48
49       ·   Format Options
50
51       ·   Filtering Options
52
53       ·   Performance Options
54
55       ·   Transactional Options
56
57       ·   Option Groups
58
59       ·   Examples
60
61       ·   Restrictions
62
63       mysqldump requires at least the SELECT privilege for dumped tables,
64       SHOW VIEW for dumped views, TRIGGER for dumped triggers, LOCK TABLES if
65       the --single-transaction option is not used, and (as of MySQL 8.0.21)
66       PROCESS if the --no-tablespaces option is not used. Certain options
67       might require other privileges as noted in the option descriptions.
68
69       To reload a dump file, you must have the privileges required to execute
70       the statements that it contains, such as the appropriate CREATE
71       privileges for objects created by those statements.
72
73       mysqldump output can include ALTER DATABASE statements that change the
74       database collation. These may be used when dumping stored programs to
75       preserve their character encodings. To reload a dump file containing
76       such statements, the ALTER privilege for the affected database is
77       required.
78
79           Note
80           A dump made using PowerShell on Windows with output redirection
81           creates a file that has UTF-16 encoding:
82
83               shell> mysqldump [options] > dump.sql
84
85           However, UTF-16 is not permitted as a connection character set (see
86           the section called “Impermissible Client Character Sets”), so the
87           dump file cannot be loaded correctly. To work around this issue,
88           use the --result-file option, which creates the output in ASCII
89           format:
90
91               shell> mysqldump [options] --result-file=dump.sql
92       Performance and Scalability Considerations
93
94       mysqldump advantages include the convenience and flexibility of viewing
95       or even editing the output before restoring. You can clone databases
96       for development and DBA work, or produce slight variations of an
97       existing database for testing. It is not intended as a fast or scalable
98       solution for backing up substantial amounts of data. With large data
99       sizes, even if the backup step takes a reasonable time, restoring the
100       data can be very slow because replaying the SQL statements involves
101       disk I/O for insertion, index creation, and so on.
102
103       For large-scale backup and restore, a physical backup is more
104       appropriate, to copy the data files in their original format that can
105       be restored quickly:
106
107       ·   If your tables are primarily InnoDB tables, or if you have a mix of
108           InnoDB and MyISAM tables, consider using the mysqlbackup command of
109           the MySQL Enterprise Backup product. (Available as part of the
110           Enterprise subscription.) It provides the best performance for
111           InnoDB backups with minimal disruption; it can also back up tables
112           from MyISAM and other storage engines; and it provides a number of
113           convenient options to accommodate different backup scenarios. See
114           Section 30.2, “MySQL Enterprise Backup Overview”.
115
116       mysqldump can retrieve and dump table contents row by row, or it can
117       retrieve the entire content from a table and buffer it in memory before
118       dumping it. Buffering in memory can be a problem if you are dumping
119       large tables. To dump tables row by row, use the --quick option (or
120       --opt, which enables --quick). The --opt option (and hence --quick) is
121       enabled by default, so to enable memory buffering, use --skip-quick.
122
123       If you are using a recent version of mysqldump to generate a dump to be
124       reloaded into a very old MySQL server, use the --skip-opt option
125       instead of the --opt or --extended-insert option.
126
127       For additional information about mysqldump, see Section 7.4, “Using
128       mysqldump for Backups”.  Invocation Syntax
129
130       There are in general three ways to use mysqldump—in order to dump a set
131       of one or more tables, a set of one or more complete databases, or an
132       entire MySQL server—as shown here:
133
134           shell> mysqldump [options] db_name [tbl_name ...]
135           shell> mysqldump [options] --databases db_name ...
136           shell> mysqldump [options] --all-databases
137
138       To dump entire databases, do not name any tables following db_name, or
139       use the --databases or --all-databases option.
140
141       To see a list of the options your version of mysqldump supports, issue
142       the command mysqldump --help.  Option Syntax - Alphabetical Summary
143
144       mysqldump supports the following options, which can be specified on the
145       command line or in the [mysqldump] and [client] groups of an option
146       file. For information about option files used by MySQL programs, see
147       Section 4.2.2.2, “Using Option Files”.  Connection Options
148
149       The mysqldump command logs into a MySQL server to extract information.
150       The following options specify how to connect to the MySQL server,
151       either on the same machine or a remote system.
152
153       ·   --bind-address=ip_address On a computer having multiple network
154           interfaces, use this option to select which interface to use for
155           connecting to the MySQL server.
156
157       ·   --compress, -C Compress all information sent between the client and
158           the server if possible. See Section 4.2.8, “Connection Compression
159           Control”.
160
161           As of MySQL 8.0.18, this option is deprecated. Expect it to be
162           removed in a future version of MySQL. See the section called
163           “Configuring Legacy Connection Compression”.
164
165       ·   --compression-algorithms=value The permitted compression algorithms
166           for connections to the server. The available algorithms are the
167           same as for the protocol_compression_algorithms system variable.
168           The default value is uncompressed.
169
170           For more information, see Section 4.2.8, “Connection Compression
171           Control”.
172
173           This option was added in MySQL 8.0.18.
174
175       ·   --default-auth=plugin A hint about which client-side authentication
176           plugin to use. See Section 6.2.17, “Pluggable Authentication”.
177
178       ·   --enable-cleartext-plugin Enable the mysql_clear_password cleartext
179           authentication plugin. (See Section 6.4.1.4, “Client-Side Cleartext
180           Pluggable Authentication”.)
181
182       ·   --get-server-public-key Request from the server the public key
183           required for RSA key pair-based password exchange. This option
184           applies to clients that authenticate with the caching_sha2_password
185           authentication plugin. For that plugin, the server does not send
186           the public key unless requested. This option is ignored for
187           accounts that do not authenticate with that plugin. It is also
188           ignored if RSA-based password exchange is not used, as is the case
189           when the client connects to the server using a secure connection.
190
191           If --server-public-key-path=file_name is given and specifies a
192           valid public key file, it takes precedence over
193           --get-server-public-key.
194
195           For information about the caching_sha2_password plugin, see
196           Section 6.4.1.2, “Caching SHA-2 Pluggable Authentication”.
197
198       ·   --host=host_name, -h host_name Dump data from the MySQL server on
199           the given host. The default host is localhost.
200
201       ·   --login-path=name Read options from the named login path in the
202           .mylogin.cnf login path file. A “login path” is an option group
203           containing options that specify which MySQL server to connect to
204           and which account to authenticate as. To create or modify a login
205           path file, use the mysql_config_editor utility. See
206           mysql_config_editor(1).
207
208           For additional information about this and other option-file
209           options, see Section 4.2.2.3, “Command-Line Options that Affect
210           Option-File Handling”.
211
212       ·   --password[=password], -p[password] The password of the MySQL
213           account used for connecting to the server. The password value is
214           optional. If not given, mysqldump prompts for one. If given, there
215           must be no space between --password= or -p and the password
216           following it. If no password option is specified, the default is to
217           send no password.
218
219           Specifying a password on the command line should be considered
220           insecure. To avoid giving the password on the command line, use an
221           option file. See Section 6.1.2.1, “End-User Guidelines for Password
222           Security”.
223
224           To explicitly specify that there is no password and that mysqldump
225           should not prompt for one, use the --skip-password option.
226
227       ·   --pipe, -W On Windows, connect to the server using a named pipe.
228           This option applies only if the server was started with the
229           named_pipe system variable enabled to support named-pipe
230           connections. In addition, the user making the connection must be a
231           member of the Windows group specified by the
232           named_pipe_full_access_group system variable.
233
234       ·   --plugin-dir=dir_name The directory in which to look for plugins.
235           Specify this option if the --default-auth option is used to specify
236           an authentication plugin but mysqldump does not find it. See
237           Section 6.2.17, “Pluggable Authentication”.
238
239       ·   --port=port_num, -P port_num For TCP/IP connections, the port
240           number to use.
241
242       ·   --protocol={TCP|SOCKET|PIPE|MEMORY} The transport protocol to use
243           for connecting to the server. It is useful when the other
244           connection parameters normally result in use of a protocol other
245           than the one you want. For details on the permissible values, see
246           Section 4.2.7, “Connection Transport Protocols”.
247
248       ·   --server-public-key-path=file_name The path name to a file in PEM
249           format containing a client-side copy of the public key required by
250           the server for RSA key pair-based password exchange. This option
251           applies to clients that authenticate with the sha256_password or
252           caching_sha2_password authentication plugin. This option is ignored
253           for accounts that do not authenticate with one of those plugins. It
254           is also ignored if RSA-based password exchange is not used, as is
255           the case when the client connects to the server using a secure
256           connection.
257
258           If --server-public-key-path=file_name is given and specifies a
259           valid public key file, it takes precedence over
260           --get-server-public-key.
261
262           For sha256_password, this option applies only if MySQL was built
263           using OpenSSL.
264
265           For information about the sha256_password and caching_sha2_password
266           plugins, see Section 6.4.1.3, “SHA-256 Pluggable Authentication”,
267           and Section 6.4.1.2, “Caching SHA-2 Pluggable Authentication”.
268
269       ·   --socket=path, -S path For connections to localhost, the Unix
270           socket file to use, or, on Windows, the name of the named pipe to
271           use.
272
273           On Windows, this option applies only if the server was started with
274           the named_pipe system variable enabled to support named-pipe
275           connections. In addition, the user making the connection must be a
276           member of the Windows group specified by the
277           named_pipe_full_access_group system variable.
278
279       ·   --ssl* Options that begin with --ssl specify whether to connect to
280           the server using SSL and indicate where to find SSL keys and
281           certificates. See the section called “Command Options for Encrypted
282           Connections”.
283
284       ·   --ssl-fips-mode={OFF|ON|STRICT} Controls whether to enable FIPS
285           mode on the client side. The --ssl-fips-mode option differs from
286           other --ssl-xxx options in that it is not used to establish
287           encrypted connections, but rather to affect which cryptographic
288           operations to permit. See Section 6.8, “FIPS Support”.
289
290           These --ssl-fips-mode values are permitted:
291
292           ·   OFF: Disable FIPS mode.
293
294           ·   ON: Enable FIPS mode.
295
296           ·   STRICT: Enable “strict” FIPS mode.
297
298
299               Note
300               If the OpenSSL FIPS Object Module is not available, the only
301               permitted value for --ssl-fips-mode is OFF. In this case,
302               setting --ssl-fips-mode to ON or STRICT causes the client to
303               produce a warning at startup and to operate in non-FIPS mode.
304
305       ·   --tls-ciphersuites=ciphersuite_list The permissible ciphersuites
306           for encrypted connections that use TLSv1.3. The value is a list of
307           one or more colon-separated ciphersuite names. The ciphersuites
308           that can be named for this option depend on the SSL library used to
309           compile MySQL. For details, see Section 6.3.2, “Encrypted
310           Connection TLS Protocols and Ciphers”.
311
312           This option was added in MySQL 8.0.16.
313
314       ·   --tls-version=protocol_list The permissible TLS protocols for
315           encrypted connections. The value is a list of one or more
316           comma-separated protocol names. The protocols that can be named for
317           this option depend on the SSL library used to compile MySQL. For
318           details, see Section 6.3.2, “Encrypted Connection TLS Protocols and
319           Ciphers”.
320
321       ·   --user=user_name, -u user_name The user name of the MySQL account
322           to use for connecting to the server.
323
324       ·   --zstd-compression-level=level The compression level to use for
325           connections to the server that use the zstd compression algorithm.
326           The permitted levels are from 1 to 22, with larger values
327           indicating increasing levels of compression. The default zstd
328           compression level is 3. The compression level setting has no effect
329           on connections that do not use zstd compression.
330
331           For more information, see Section 4.2.8, “Connection Compression
332           Control”.
333
334           This option was added in MySQL 8.0.18.
335       Option-File Options
336
337       These options are used to control which option files to read.
338
339       ·   --defaults-extra-file=file_name Read this option file after the
340           global option file but (on Unix) before the user option file. If
341           the file does not exist or is otherwise inaccessible, an error
342           occurs.  file_name is interpreted relative to the current directory
343           if given as a relative path name rather than a full path name.
344
345           For additional information about this and other option-file
346           options, see Section 4.2.2.3, “Command-Line Options that Affect
347           Option-File Handling”.
348
349       ·   --defaults-file=file_name Use only the given option file. If the
350           file does not exist or is otherwise inaccessible, an error occurs.
351           file_name is interpreted relative to the current directory if given
352           as a relative path name rather than a full path name.
353
354           Exception: Even with --defaults-file, client programs read
355           .mylogin.cnf.
356
357           For additional information about this and other option-file
358           options, see Section 4.2.2.3, “Command-Line Options that Affect
359           Option-File Handling”.
360
361       ·   --defaults-group-suffix=str Read not only the usual option groups,
362           but also groups with the usual names and a suffix of str. For
363           example, mysqldump normally reads the [client] and [mysqldump]
364           groups. If the --defaults-group-suffix=_other option is given,
365           mysqldump also reads the [client_other] and [mysqldump_other]
366           groups.
367
368           For additional information about this and other option-file
369           options, see Section 4.2.2.3, “Command-Line Options that Affect
370           Option-File Handling”.
371
372       ·   --no-defaults Do not read any option files. If program startup
373           fails due to reading unknown options from an option file,
374           --no-defaults can be used to prevent them from being read.
375
376           The exception is that the .mylogin.cnf file, if it exists, is read
377           in all cases. This permits passwords to be specified in a safer way
378           than on the command line even when --no-defaults is used.
379           (.mylogin.cnf is created by the mysql_config_editor utility. See
380           mysql_config_editor(1).)
381
382           For additional information about this and other option-file
383           options, see Section 4.2.2.3, “Command-Line Options that Affect
384           Option-File Handling”.
385
386       ·   --print-defaults Print the program name and all options that it
387           gets from option files.
388
389           For additional information about this and other option-file
390           options, see Section 4.2.2.3, “Command-Line Options that Affect
391           Option-File Handling”.
392       DDL Options
393
394       Usage scenarios for mysqldump include setting up an entire new MySQL
395       instance (including database tables), and replacing data inside an
396       existing instance with existing databases and tables. The following
397       options let you specify which things to tear down and set up when
398       restoring a dump, by encoding various DDL statements within the dump
399       file.
400
401       ·   --add-drop-database Write a DROP DATABASE statement before each
402           CREATE DATABASE statement. This option is typically used in
403           conjunction with the --all-databases or --databases option because
404           no CREATE DATABASE statements are written unless one of those
405           options is specified.
406
407               Note
408               In MySQL 8.0, the mysql schema is considered a system schema
409               that cannot be dropped by end users. If --add-drop-database is
410               used with --all-databases or with --databases where the list of
411               schemas to be dumped includes mysql, the dump file contains a
412               DROP DATABASE `mysql` statement that causes an error when the
413               dump file is reloaded.
414
415               Instead, to use --add-drop-database, use --databases with a
416               list of schemas to be dumped, where the list does not include
417               mysql.
418
419       ·   --add-drop-table Write a DROP TABLE statement before each CREATE
420           TABLE statement.
421
422       ·   --add-drop-trigger Write a DROP TRIGGER statement before each
423           CREATE TRIGGER statement.
424
425       ·   --all-tablespaces, -Y Adds to a table dump all SQL statements
426           needed to create any tablespaces used by an NDB table. This
427           information is not otherwise included in the output from mysqldump.
428           This option is currently relevant only to NDB Cluster tables.
429
430       ·   --no-create-db, -n Suppress the CREATE DATABASE statements that are
431           otherwise included in the output if the --databases or
432           --all-databases option is given.
433
434       ·   --no-create-info, -t Do not write CREATE TABLE statements that
435           create each dumped table.
436
437               Note
438               This option does not exclude statements creating log file
439               groups or tablespaces from mysqldump output; however, you can
440               use the --no-tablespaces option for this purpose.
441
442       ·   --no-tablespaces, -y This option suppresses all CREATE LOGFILE
443           GROUP and CREATE TABLESPACE statements in the output of mysqldump.
444
445       ·   --replace Write REPLACE statements rather than INSERT statements.
446       Debug Options
447
448       The following options print debugging information, encode debugging
449       information in the dump file, or let the dump operation proceed
450       regardless of potential problems.
451
452       ·   --allow-keywords Permit creation of column names that are keywords.
453           This works by prefixing each column name with the table name.
454
455       ·   --comments, -i Write additional information in the dump file such
456           as program version, server version, and host. This option is
457           enabled by default. To suppress this additional information, use
458           --skip-comments.
459
460       ·   --debug[=debug_options], -# [debug_options] Write a debugging log.
461           A typical debug_options string is d:t:o,file_name. The default
462           value is d:t:o,/tmp/mysqldump.trace.
463
464           This option is available only if MySQL was built using WITH_DEBUG.
465           MySQL release binaries provided by Oracle are not built using this
466           option.
467
468       ·   --debug-check Print some debugging information when the program
469           exits.
470
471           This option is available only if MySQL was built using WITH_DEBUG.
472           MySQL release binaries provided by Oracle are not built using this
473           option.
474
475       ·   --debug-info Print debugging information and memory and CPU usage
476           statistics when the program exits.
477
478           This option is available only if MySQL was built using WITH_DEBUG.
479           MySQL release binaries provided by Oracle are not built using this
480           option.
481
482       ·   --dump-date If the --comments option is given, mysqldump produces a
483           comment at the end of the dump of the following form:
484
485               -- Dump completed on DATE
486
487           However, the date causes dump files taken at different times to
488           appear to be different, even if the data are otherwise identical.
489           --dump-date and --skip-dump-date control whether the date is added
490           to the comment. The default is --dump-date (include the date in the
491           comment).  --skip-dump-date suppresses date printing.
492
493       ·   --force, -f Ignore all errors; continue even if an SQL error occurs
494           during a table dump.
495
496           One use for this option is to cause mysqldump to continue executing
497           even when it encounters a view that has become invalid because the
498           definition refers to a table that has been dropped. Without
499           --force, mysqldump exits with an error message. With --force,
500           mysqldump prints the error message, but it also writes an SQL
501           comment containing the view definition to the dump output and
502           continues executing.
503
504           If the --ignore-error option is also given to ignore specific
505           errors, --force takes precedence.
506
507       ·   --log-error=file_name Log warnings and errors by appending them to
508           the named file. The default is to do no logging.
509
510       ·   --skip-comments See the description for the --comments option.
511
512       ·   --verbose, -v Verbose mode. Print more information about what the
513           program does.
514       Help Options
515
516       The following options display information about the mysqldump command
517       itself.
518
519       ·   --help, -?  Display a help message and exit.
520
521       ·   --version, -V Display version information and exit.
522       Internationalization Options
523
524       The following options change how the mysqldump command represents
525       character data with national language settings.
526
527       ·   --character-sets-dir=dir_name The directory where character sets
528           are installed. See Section 10.15, “Character Set Configuration”.
529
530       ·   --default-character-set=charset_name Use charset_name as the
531           default character set. See Section 10.15, “Character Set
532           Configuration”. If no character set is specified, mysqldump uses
533           utf8.
534
535       ·   --no-set-names, -N Turns off the --set-charset setting, the same as
536           specifying --skip-set-charset.
537
538       ·   --set-charset Write SET NAMES default_character_set to the output.
539           This option is enabled by default. To suppress the SET NAMES
540           statement, use --skip-set-charset.
541       Replication Options
542
543       The mysqldump command is frequently used to create an empty instance,
544       or an instance including data, on a replica server in a replication
545       configuration. The following options apply to dumping and restoring
546       data on replication source servers and replicas.
547
548       ·   --apply-slave-statements For a replica dump produced with the
549           --dump-slave option, add a STOP REPLICA | SLAVE statement before
550           the CHANGE MASTER TO statement and a START REPLICA | SLAVE
551           statement at the end of the output.
552
553       ·   --delete-master-logs On a replication source server, delete the
554           binary logs by sending a PURGE BINARY LOGS statement to the server
555           after performing the dump operation. This option requires the
556           RELOAD privilege as well as privileges sufficient to execute that
557           statement. This option automatically enables --master-data.
558
559       ·   --dump-slave[=value] This option is similar to --master-data except
560           that it is used to dump a replica server to produce a dump file
561           that can be used to set up another server as a replica that has the
562           same source as the dumped server. It causes the dump output to
563           include a CHANGE MASTER TO statement that indicates the binary log
564           coordinates (file name and position) of the dumped replica's
565           source. The CHANGE MASTER TO statement reads the values of
566           Relay_Master_Log_File and Exec_Master_Log_Pos from the SHOW REPLICA
567           | SLAVE STATUS output and uses them for MASTER_LOG_FILE and
568           MASTER_LOG_POS respectively. These are the replication source
569           server coordinates from which the replica starts replicating.
570
571               Note
572               Inconsistencies in the sequence of transactions from the relay
573               log which have been executed can cause the wrong position to be
574               used. See Section 17.5.1.34, “Replication and Transaction
575               Inconsistencies” for more information.
576           --dump-slave causes the coordinates from the source to be used
577           rather than those of the dumped server, as is done by the
578           --master-data option. In addition, specifiying this option causes
579           the --master-data option to be overridden, if used, and effectively
580           ignored.
581
582               Warning
583               This option should not be used if the server where the dump is
584               going to be applied uses gtid_mode=ON and
585               MASTER_AUTOPOSITION=1.
586           The option value is handled the same way as for --master-data
587           (setting no value or 1 causes a CHANGE MASTER TO statement to be
588           written to the dump, setting 2 causes the statement to be written
589           but encased in SQL comments) and has the same effect as
590           --master-data in terms of enabling or disabling other options and
591           in how locking is handled.
592
593           This option causes mysqldump to stop the replication SQL thread
594           before the dump and restart it again after.
595
596           --dump-slave sends a SHOW REPLICA | SLAVE STATUS statement to the
597           server to obtain information, so it requires privileges sufficient
598           to execute that statement.
599
600           In conjunction with --dump-slave, the --apply-slave-statements and
601           --include-master-host-port options can also be used.
602
603       ·   --include-master-host-port For the CHANGE MASTER TO statement in a
604           replica dump produced with the --dump-slave option, add MASTER_HOST
605           and MASTER_PORT options for the host name and TCP/IP port number of
606           the replica's source.
607
608       ·   --master-data[=value] Use this option to dump a replication source
609           server to produce a dump file that can be used to set up another
610           server as a replica of the source. It causes the dump output to
611           include a CHANGE MASTER TO statement that indicates the binary log
612           coordinates (file name and position) of the dumped server. These
613           are the replication source server coordinates from which the
614           replica should start replicating after you load the dump file into
615           the replica.
616
617           If the option value is 2, the CHANGE MASTER TO statement is written
618           as an SQL comment, and thus is informative only; it has no effect
619           when the dump file is reloaded. If the option value is 1, the
620           statement is not written as a comment and takes effect when the
621           dump file is reloaded. If no option value is specified, the default
622           value is 1.
623
624           --master-data sends a SHOW MASTER STATUS statement to the server to
625           obtain information, so it requires privileges sufficient to execute
626           that statement. This option also requires the RELOAD privilege and
627           the binary log must be enabled.
628
629           The --master-data option automatically turns off --lock-tables. It
630           also turns on --lock-all-tables, unless --single-transaction also
631           is specified, in which case, a global read lock is acquired only
632           for a short time at the beginning of the dump (see the description
633           for --single-transaction). In all cases, any action on logs happens
634           at the exact moment of the dump.
635
636           It is also possible to set up a replica by dumping an existing
637           replica of the source, using the --dump-slave option, which
638           overrides --master-data and causes it to be ignored if both options
639           are used.
640
641       ·   --set-gtid-purged=value This option is for servers that use
642           GTID-based replication (gtid_mode=ON). It controls the inclusion of
643           a SET @@GLOBAL.gtid_purged statement in the dump output, which
644           updates the value of gtid_purged on a server where the dump file is
645           reloaded, to add the GTID set from the source server's
646           gtid_executed system variable.  gtid_purged holds the GTIDs of all
647           transactions that have been applied on the server, but do not exist
648           on any binary log file on the server.  mysqldump therefore adds the
649           GTIDs for the transactions that were executed on the source server,
650           so that the target server records these transactions as applied,
651           although it does not have them in its binary logs.
652           --set-gtid-purged also controls the inclusion of a SET
653           @@SESSION.sql_log_bin=0 statement, which disables binary logging
654           while the dump file is being reloaded. This statement prevents new
655           GTIDs from being generated and assigned to the transactions in the
656           dump file as they are executed, so that the original GTIDs for the
657           transactions are used.
658
659           If you do not set the --set-gtid-purged option, the default is that
660           a SET @@GLOBAL.gtid_purged statement is included in the dump output
661           if GTIDs are enabled on the server you are backing up, and the set
662           of GTIDs in the global value of the gtid_executed system variable
663           is not empty. A SET @@SESSION.sql_log_bin=0 statement is also
664           included if GTIDs are enabled on the server.
665
666           In MySQL 5.6 and 5.7, you can replace the value of gtid_purged with
667           a specified GTID set, provided that gtid_executed and gtid_purged
668           are empty. From MySQL 8.0, you can either replace the value of
669           gtid_purged with a specified GTID set, or you can add a plus sign
670           (+) to the statement to append a specified GTID set to the GTID set
671           that is already held by gtid_purged.  mysqldump's SET
672           @@GLOBAL.gtid_purged statement includes a plus sign (+) in a
673           version comment that takes effect when the dump file is replayed on
674           releases from MySQL 8.0, meaning that for these releases, the GTID
675           set from the dump file is added to the existing gtid_purged value.
676           For MySQL 5.6 and 5.7, the value of gtid_purged is replaced with
677           the GTID set from the dump file, which can only happen when
678           gtid_executed is the empty set (so when replication has not been
679           started previously, or when replication was not previously using
680           GTIDs). For the exact details of how the SET @@GLOBAL.gtid_purged
681           statement operates, see the gtid_purged description for the release
682           where the dump file is to be replayed.
683
684           It is important to note that the value that is included by
685           mysqldump for the SET @@GLOBAL.gtid_purged statement includes the
686           GTIDs of all transactions in the gtid_executed set on the server,
687           even those that changed suppressed parts of the database, or other
688           databases on the server that were not included in a partial dump.
689           This can mean that after the gtid_purged value has been updated on
690           the server where the dump file is replayed, GTIDs are present that
691           do not relate to any data on the target server. If you do not
692           replay any further dump files on the target server, the extraneous
693           GTIDs do not cause any problems with the future operation of the
694           server, but they make it harder to compare or reconcile GTID sets
695           on different servers in the replication topology. If you do replay
696           a further dump file on the target server that contains the same
697           GTIDs (for example, another partial dump from the same origin
698           server), any SET @@GLOBAL.gtid_purged statement in the second dump
699           file fails. In this case, either remove the statement manually
700           before replaying the dump file, or output the dump file without the
701           statement.
702
703               Note
704               For MySQL 5.6 and 5.7, it is not recommended to load a dump
705               file when GTIDs are enabled on the server (gtid_mode=ON), if
706               your dump file includes system tables.  mysqldump issues DML
707               instructions for the system tables which use the
708               non-transactional MyISAM storage engine, and this combination
709               is not permitted when GTIDs are enabled.
710           If the SET @@GLOBAL.gtid_purged statement would not have the
711           desired result on your target server, you can exclude the statement
712           from the output, or (from MySQL 8.0.17) include it but comment it
713           out so that it is not actioned automatically. You can also include
714           the statement but manually edit it in the dump file to achieve the
715           desired result.
716
717           The possible values for the --set-gtid-purged option are as
718           follows:
719
720           AUTO
721               The default value. If GTIDs are enabled on the server you are
722               backing up and gtid_executed is not empty, SET
723               @@GLOBAL.gtid_purged is added to the output, containing the
724               GTID set from gtid_executed. If GTIDs are enabled, SET
725               @@SESSION.sql_log_bin=0 is added to the output. If GTIDs are
726               not enabled on the server, the statements are not added to the
727               output.
728
729           OFF
730               SET @@GLOBAL.gtid_purged is not added to the output, and SET
731               @@SESSION.sql_log_bin=0 is not added to the output. For a
732               server where GTIDs are not in use, use this option or AUTO.
733               Only use this option for a server where GTIDs are in use if you
734               are sure that the required GTID set is already present in
735               gtid_purged on the target server and should not be changed, or
736               if you plan to identify and add any missing GTIDs manually.
737
738           ON
739               If GTIDs are enabled on the server you are backing up, SET
740               @@GLOBAL.gtid_purged is added to the output (unless
741               gtid_executed is empty), and SET @@SESSION.sql_log_bin=0 is
742               added to the output. An error occurs if you set this option but
743               GTIDs are not enabled on the server. For a server where GTIDs
744               are in use, use this option or AUTO, unless you are sure that
745               the GTIDs in gtid_executed are not needed on the target server.
746
747           COMMENTED
748               Available from MySQL 8.0.17. If GTIDs are enabled on the server
749               you are backing up, SET @@GLOBAL.gtid_purged is added to the
750               output (unless gtid_executed is empty), but it is commented
751               out. This means that the value of gtid_executed is available in
752               the output, but no action is taken automatically when the dump
753               file is reloaded.  SET @@SESSION.sql_log_bin=0 is added to the
754               output, and it is not commented out. With COMMENTED, you can
755               control the use of the gtid_executed set manually or through
756               automation. For example, you might prefer to do this if you are
757               migrating data to another server that already has different
758               active databases.
759       Format Options
760
761       The following options specify how to represent the entire dump file or
762       certain kinds of data in the dump file. They also control whether
763       certain optional information is written to the dump file.
764
765       ·   --compact Produce more compact output. This option enables the
766           --skip-add-drop-table, --skip-add-locks, --skip-comments,
767           --skip-disable-keys, and --skip-set-charset options.
768
769       ·   --compatible=name Produce output that is more compatible with other
770           database systems or with older MySQL servers. The only permitted
771           value for this option is ansi, which has the same meaning as the
772           corresponding option for setting the server SQL mode. See
773           Section 5.1.11, “Server SQL Modes”.
774
775       ·   --complete-insert, -c Use complete INSERT statements that include
776           column names.
777
778       ·   --create-options Include all MySQL-specific table options in the
779           CREATE TABLE statements.
780
781       ·   --fields-terminated-by=..., --fields-enclosed-by=...,
782           --fields-optionally-enclosed-by=..., --fields-escaped-by=...  These
783           options are used with the --tab option and have the same meaning as
784           the corresponding FIELDS clauses for LOAD DATA. See Section 13.2.7,
785           “LOAD DATA Statement”.
786
787       ·   --hex-blob Dump binary columns using hexadecimal notation (for
788           example, 'abc' becomes 0x616263). The affected data types are
789           BINARY, VARBINARY, BLOB types, BIT, all spatial data types, and
790           other non-binary data types when used with the binary character
791           set.
792
793       ·   --lines-terminated-by=...  This option is used with the --tab
794           option and has the same meaning as the corresponding LINES clause
795           for LOAD DATA. See Section 13.2.7, “LOAD DATA Statement”.
796
797       ·   --quote-names, -Q Quote identifiers (such as database, table, and
798           column names) within ` characters. If the ANSI_QUOTES SQL mode is
799           enabled, identifiers are quoted within " characters. This option is
800           enabled by default. It can be disabled with --skip-quote-names, but
801           this option should be given after any option such as --compatible
802           that may enable --quote-names.
803
804       ·   --result-file=file_name, -r file_name Direct output to the named
805           file. The result file is created and its previous contents
806           overwritten, even if an error occurs while generating the dump.
807
808           This option should be used on Windows to prevent newline \n
809           characters from being converted to \r\n carriage return/newline
810           sequences.
811
812       ·   --show-create-skip-secondary-engine=value Excludes the SECONDARY
813           ENGINE clause from CREATE TABLE statements. It does so by enabling
814           the show_create_table_skip_secondary_engine system variable for the
815           duration of the dump operation. Alternatively, you can enable the
816           show_create_table_skip_secondary_engine system variable prior to
817           using mysqldump.
818
819           This option was added in MySQL 8.0.18. Attempting a mysqldump
820           operation with the --show-create-skip-secondary-engine option on a
821           release prior to MySQL 8.0.18 that does not support the
822           show_create_table_skip_secondary_engine variable causes an error.
823
824       ·   --tab=dir_name, -T dir_name Produce tab-separated text-format data
825           files. For each dumped table, mysqldump creates a tbl_name.sql file
826           that contains the CREATE TABLE statement that creates the table,
827           and the server writes a tbl_name.txt file that contains its data.
828           The option value is the directory in which to write the files.
829
830               Note
831               This option should be used only when mysqldump is run on the
832               same machine as the mysqld server. Because the server creates
833               *.txt files in the directory that you specify, the directory
834               must be writable by the server and the MySQL account that you
835               use must have the FILE privilege. Because mysqldump creates
836               *.sql in the same directory, it must be writable by your system
837               login account.
838           By default, the .txt data files are formatted using tab characters
839           between column values and a newline at the end of each line. The
840           format can be specified explicitly using the --fields-xxx and
841           --lines-terminated-by options.
842
843           Column values are converted to the character set specified by the
844           --default-character-set option.
845
846       ·   --tz-utc This option enables TIMESTAMP columns to be dumped and
847           reloaded between servers in different time zones.  mysqldump sets
848           its connection time zone to UTC and adds SET TIME_ZONE='+00:00' to
849           the dump file. Without this option, TIMESTAMP columns are dumped
850           and reloaded in the time zones local to the source and destination
851           servers, which can cause the values to change if the servers are in
852           different time zones.  --tz-utc also protects against changes due
853           to daylight saving time.  --tz-utc is enabled by default. To
854           disable it, use --skip-tz-utc.
855
856       ·   --xml, -X Write dump output as well-formed XML.
857
858           NULL, 'NULL', and Empty Values: For a column named column_name, the
859           NULL value, an empty string, and the string value 'NULL' are
860           distinguished from one another in the output generated by this
861           option as follows.
862
863           ┌─────────────────────┬────────────────────────────────────────────┐
864Value:               XML Representation:                        
865           ├─────────────────────┼────────────────────────────────────────────┤
866           │NULL (unknown value) │                                            │
867           │                     │            <field                          │
868           │                     │            name="column_name"              │
869           │                     │            xsi:nil="true"                  │
870           │                     │            />                              │
871           ├─────────────────────┼────────────────────────────────────────────┤
872           │                     │                                            │
873           │                     │            <field                          │
874           │                     │            name="column_name"></field>     │
875           ├─────────────────────┼────────────────────────────────────────────┤
876           │                     │                                            │
877           │                     │            <field                          │
878           │                     │            name="column_name">NULL</field> │
879           └─────────────────────┴────────────────────────────────────────────┘
880           The output from the mysql client when run using the --xml option
881           also follows the preceding rules. (See the section called “MYSQL
882           CLIENT OPTIONS”.)
883
884           XML output from mysqldump includes the XML namespace, as shown
885           here:
886
887               shell> mysqldump --xml -u root world City
888               <?xml version="1.0"?>
889               <mysqldump xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance">
890               <database name="world">
891               <table_structure name="City">
892               <field Field="ID" Type="int(11)" Null="NO" Key="PRI" Extra="auto_increment" />
893               <field Field="Name" Type="char(35)" Null="NO" Key="" Default="" Extra="" />
894               <field Field="CountryCode" Type="char(3)" Null="NO" Key="" Default="" Extra="" />
895               <field Field="District" Type="char(20)" Null="NO" Key="" Default="" Extra="" />
896               <field Field="Population" Type="int(11)" Null="NO" Key="" Default="0" Extra="" />
897               <key Table="City" Non_unique="0" Key_name="PRIMARY" Seq_in_index="1" Column_name="ID"
898               Collation="A" Cardinality="4079" Null="" Index_type="BTREE" Comment="" />
899               <options Name="City" Engine="MyISAM" Version="10" Row_format="Fixed" Rows="4079"
900               Avg_row_length="67" Data_length="273293" Max_data_length="18858823439613951"
901               Index_length="43008" Data_free="0" Auto_increment="4080"
902               Create_time="2007-03-31 01:47:01" Update_time="2007-03-31 01:47:02"
903               Collation="latin1_swedish_ci" Create_options="" Comment="" />
904               </table_structure>
905               <table_data name="City">
906               <row>
907               <field name="ID">1</field>
908               <field name="Name">Kabul</field>
909               <field name="CountryCode">AFG</field>
910               <field name="District">Kabol</field>
911               <field name="Population">1780000</field>
912               </row>
913               ...
914               <row>
915               <field name="ID">4079</field>
916               <field name="Name">Rafah</field>
917               <field name="CountryCode">PSE</field>
918               <field name="District">Rafah</field>
919               <field name="Population">92020</field>
920               </row>
921               </table_data>
922               </database>
923               </mysqldump>
924       Filtering Options
925
926       The following options control which kinds of schema objects are written
927       to the dump file: by category, such as triggers or events; by name, for
928       example, choosing which databases and tables to dump; or even filtering
929       rows from the table data using a WHERE clause.
930
931       ·   --all-databases, -A Dump all tables in all databases. This is the
932           same as using the --databases option and naming all the databases
933           on the command line.
934
935               Note
936               See the --add-drop-database description for information about
937               an incompatibility of that option with --all-databases.
938           Prior to MySQL 8.0, the --routines and --events options for
939           mysqldump and mysqlpump were not required to include stored
940           routines and events when using the --all-databases option: The dump
941           included the mysql system database, and therefore also the
942           mysql.proc and mysql.event tables containing stored routine and
943           event definitions. As of MySQL 8.0, the mysql.event and mysql.proc
944           tables are not used. Definitions for the corresponding objects are
945           stored in data dictionary tables, but those tables are not dumped.
946           To include stored routines and events in a dump made using
947           --all-databases, use the --routines and --events options
948           explicitly.
949
950       ·   --databases, -B Dump several databases. Normally, mysqldump treats
951           the first name argument on the command line as a database name and
952           following names as table names. With this option, it treats all
953           name arguments as database names.  CREATE DATABASE and USE
954           statements are included in the output before each new database.
955
956           This option may be used to dump the performance_schema database,
957           which normally is not dumped even with the --all-databases option.
958           (Also use the --skip-lock-tables option.)
959
960               Note
961               See the --add-drop-database description for information about
962               an incompatibility of that option with --databases.
963
964       ·   --events, -E Include Event Scheduler events for the dumped
965           databases in the output. This option requires the EVENT privileges
966           for those databases.
967
968           The output generated by using --events contains CREATE EVENT
969           statements to create the events.
970
971       ·   --ignore-error=error[,error]...  Ignore the specified errors. The
972           option value is a list of comma-separated error numbers specifying
973           the errors to ignore during mysqldump execution. If the --force
974           option is also given to ignore all errors, --force takes
975           precedence.
976
977       ·   --ignore-table=db_name.tbl_name Do not dump the given table, which
978           must be specified using both the database and table names. To
979           ignore multiple tables, use this option multiple times. This option
980           also can be used to ignore views.
981
982       ·   --no-data, -d Do not write any table row information (that is, do
983           not dump table contents). This is useful if you want to dump only
984           the CREATE TABLE statement for the table (for example, to create an
985           empty copy of the table by loading the dump file).
986
987       ·   --routines, -R Include stored routines (procedures and functions)
988           for the dumped databases in the output. This option requires the
989           global SELECT privilege.
990
991           The output generated by using --routines contains CREATE PROCEDURE
992           and CREATE FUNCTION statements to create the routines.
993
994       ·   --tables Override the --databases or -B option.  mysqldump regards
995           all name arguments following the option as table names.
996
997       ·   --triggers Include triggers for each dumped table in the output.
998           This option is enabled by default; disable it with --skip-triggers.
999
1000           To be able to dump a table's triggers, you must have the TRIGGER
1001           privilege for the table.
1002
1003           Multiple triggers are permitted.  mysqldump dumps triggers in
1004           activation order so that when the dump file is reloaded, triggers
1005           are created in the same activation order. However, if a mysqldump
1006           dump file contains multiple triggers for a table that have the same
1007           trigger event and action time, an error occurs for attempts to load
1008           the dump file into an older server that does not support multiple
1009           triggers. (For a workaround, see Downgrade Notes[4]; you can
1010           convert triggers to be compatible with older servers.)
1011
1012       ·   --where='where_condition', -w 'where_condition' Dump only rows
1013           selected by the given WHERE condition. Quotes around the condition
1014           are mandatory if it contains spaces or other characters that are
1015           special to your command interpreter.
1016
1017           Examples:
1018
1019               --where="user='jimf'"
1020               -w"userid>1"
1021               -w"userid<1"
1022       Performance Options
1023
1024       The following options are the most relevant for the performance
1025       particularly of the restore operations. For large data sets, restore
1026       operation (processing the INSERT statements in the dump file) is the
1027       most time-consuming part. When it is urgent to restore data quickly,
1028       plan and test the performance of this stage in advance. For restore
1029       times measured in hours, you might prefer an alternative backup and
1030       restore solution, such as MySQL Enterprise Backup for InnoDB-only and
1031       mixed-use databases.
1032
1033       Performance is also affected by the transactional options, primarily
1034       for the dump operation.
1035
1036       ·   --column-statistics Add ANALYZE TABLE statements to the output to
1037           generate histogram statistics for dumped tables when the dump file
1038           is reloaded. This option is disabled by default because histogram
1039           generation for large tables can take a long time.
1040
1041       ·   --disable-keys, -K For each table, surround the INSERT statements
1042           with /*!40000 ALTER TABLE tbl_name DISABLE KEYS */; and /*!40000
1043           ALTER TABLE tbl_name ENABLE KEYS */; statements. This makes loading
1044           the dump file faster because the indexes are created after all rows
1045           are inserted. This option is effective only for nonunique indexes
1046           of MyISAM tables.
1047
1048       ·   --extended-insert, -e Write INSERT statements using multiple-row
1049           syntax that includes several VALUES lists. This results in a
1050           smaller dump file and speeds up inserts when the file is reloaded.
1051
1052       ·   --insert-ignore Write INSERT IGNORE statements rather than INSERT
1053           statements.
1054
1055       ·   --max-allowed-packet=value The maximum size of the buffer for
1056           client/server communication. The default is 24MB, the maximum is
1057           1GB.
1058
1059       ·   --net-buffer-length=value The initial size of the buffer for
1060           client/server communication. When creating multiple-row INSERT
1061           statements (as with the --extended-insert or --opt option),
1062           mysqldump creates rows up to --net-buffer-length bytes long. If you
1063           increase this variable, ensure that the MySQL server
1064           net_buffer_length system variable has a value at least this large.
1065
1066       ·   --network-timeout, -M Enable large tables to be dumped by setting
1067           --max-allowed-packet to its maximum value and network read and
1068           write timeouts to a large value. This option is enabled by default.
1069           To disable it, use --skip-network-timeout.
1070
1071       ·   --opt This option, enabled by default, is shorthand for the
1072           combination of --add-drop-table --add-locks --create-options
1073           --disable-keys --extended-insert --lock-tables --quick
1074           --set-charset. It gives a fast dump operation and produces a dump
1075           file that can be reloaded into a MySQL server quickly.
1076
1077           Because the --opt option is enabled by default, you only specify
1078           its converse, the --skip-opt to turn off several default settings.
1079           See the discussion of mysqldump option groups for information about
1080           selectively enabling or disabling a subset of the options affected
1081           by --opt.
1082
1083       ·   --quick, -q This option is useful for dumping large tables. It
1084           forces mysqldump to retrieve rows for a table from the server a row
1085           at a time rather than retrieving the entire row set and buffering
1086           it in memory before writing it out.
1087
1088       ·   --skip-opt See the description for the --opt option.
1089       Transactional Options
1090
1091       The following options trade off the performance of the dump operation,
1092       against the reliability and consistency of the exported data.
1093
1094       ·   --add-locks Surround each table dump with LOCK TABLES and UNLOCK
1095           TABLES statements. This results in faster inserts when the dump
1096           file is reloaded. See Section 8.2.5.1, “Optimizing INSERT
1097           Statements”.
1098
1099       ·   --flush-logs, -F Flush the MySQL server log files before starting
1100           the dump. This option requires the RELOAD privilege. If you use
1101           this option in combination with the --all-databases option, the
1102           logs are flushed for each database dumped. The exception is when
1103           using --lock-all-tables, --master-data, or --single-transaction: In
1104           this case, the logs are flushed only once, corresponding to the
1105           moment that all tables are locked by FLUSH TABLES WITH READ LOCK.
1106           If you want your dump and the log flush to happen at exactly the
1107           same moment, you should use --flush-logs together with
1108           --lock-all-tables, --master-data, or --single-transaction.
1109
1110       ·   --flush-privileges Add a FLUSH PRIVILEGES statement to the dump
1111           output after dumping the mysql database. This option should be used
1112           any time the dump contains the mysql database and any other
1113           database that depends on the data in the mysql database for proper
1114           restoration.
1115
1116           Because the dump file contains a FLUSH PRIVILEGES statement,
1117           reloading the file requires privileges sufficient to execute that
1118           statement.
1119
1120
1121               Note
1122               For upgrades to MySQL 5.7 or higher from older versions, do not
1123               use --flush-privileges. For upgrade instructions in this case,
1124               see Section 2.11.4, “Changes in MySQL 8.0”.
1125
1126       ·   --lock-all-tables, -x Lock all tables across all databases. This is
1127           achieved by acquiring a global read lock for the duration of the
1128           whole dump. This option automatically turns off
1129           --single-transaction and --lock-tables.
1130
1131       ·   --lock-tables, -l For each dumped database, lock all tables to be
1132           dumped before dumping them. The tables are locked with READ LOCAL
1133           to permit concurrent inserts in the case of MyISAM tables. For
1134           transactional tables such as InnoDB, --single-transaction is a much
1135           better option than --lock-tables because it does not need to lock
1136           the tables at all.
1137
1138           Because --lock-tables locks tables for each database separately,
1139           this option does not guarantee that the tables in the dump file are
1140           logically consistent between databases. Tables in different
1141           databases may be dumped in completely different states.
1142
1143           Some options, such as --opt, automatically enable --lock-tables. If
1144           you want to override this, use --skip-lock-tables at the end of the
1145           option list.
1146
1147       ·   --no-autocommit Enclose the INSERT statements for each dumped table
1148           within SET autocommit = 0 and COMMIT statements.
1149
1150       ·   --order-by-primary Dump each table's rows sorted by its primary
1151           key, or by its first unique index, if such an index exists. This is
1152           useful when dumping a MyISAM table to be loaded into an InnoDB
1153           table, but makes the dump operation take considerably longer.
1154
1155       ·   --shared-memory-base-name=name On Windows, the shared-memory name
1156           to use for connections made using shared memory to a local server.
1157           The default value is MYSQL. The shared-memory name is
1158           case-sensitive.
1159
1160           This option applies only if the server was started with the
1161           shared_memory system variable enabled to support shared-memory
1162           connections.
1163
1164       ·   --single-transaction This option sets the transaction isolation
1165           mode to REPEATABLE READ and sends a START TRANSACTION SQL statement
1166           to the server before dumping data. It is useful only with
1167           transactional tables such as InnoDB, because then it dumps the
1168           consistent state of the database at the time when START TRANSACTION
1169           was issued without blocking any applications.
1170
1171           When using this option, you should keep in mind that only InnoDB
1172           tables are dumped in a consistent state. For example, any MyISAM or
1173           MEMORY tables dumped while using this option may still change
1174           state.
1175
1176           While a --single-transaction dump is in process, to ensure a valid
1177           dump file (correct table contents and binary log coordinates), no
1178           other connection should use the following statements: ALTER TABLE,
1179           CREATE TABLE, DROP TABLE, RENAME TABLE, TRUNCATE TABLE. A
1180           consistent read is not isolated from those statements, so use of
1181           them on a table to be dumped can cause the SELECT that is performed
1182           by mysqldump to retrieve the table contents to obtain incorrect
1183           contents or fail.
1184
1185           The --single-transaction option and the --lock-tables option are
1186           mutually exclusive because LOCK TABLES causes any pending
1187           transactions to be committed implicitly.
1188
1189           To dump large tables, combine the --single-transaction option with
1190           the --quick option.
1191       Option Groups
1192
1193       ·   The --opt option turns on several settings that work together to
1194           perform a fast dump operation. All of these settings are on by
1195           default, because --opt is on by default. Thus you rarely if ever
1196           specify --opt. Instead, you can turn these settings off as a group
1197           by specifying --skip-opt, the optionally re-enable certain settings
1198           by specifying the associated options later on the command line.
1199
1200       ·   The --compact option turns off several settings that control
1201           whether optional statements and comments appear in the output.
1202           Again, you can follow this option with other options that re-enable
1203           certain settings, or turn all the settings on by using the
1204           --skip-compact form.
1205
1206       When you selectively enable or disable the effect of a group option,
1207       order is important because options are processed first to last. For
1208       example, --disable-keys --lock-tables --skip-opt would not have the
1209       intended effect; it is the same as --skip-opt by itself.  Examples
1210
1211       To make a backup of an entire database:
1212
1213           shell> mysqldump db_name > backup-file.sql
1214
1215       To load the dump file back into the server:
1216
1217           shell> mysql db_name < backup-file.sql
1218
1219       Another way to reload the dump file:
1220
1221           shell> mysql -e "source /path-to-backup/backup-file.sql" db_name
1222
1223       mysqldump is also very useful for populating databases by copying data
1224       from one MySQL server to another:
1225
1226           shell> mysqldump --opt db_name | mysql --host=remote_host -C db_name
1227
1228       You can dump several databases with one command:
1229
1230           shell> mysqldump --databases db_name1 [db_name2 ...] > my_databases.sql
1231
1232       To dump all databases, use the --all-databases option:
1233
1234           shell> mysqldump --all-databases > all_databases.sql
1235
1236       For InnoDB tables, mysqldump provides a way of making an online backup:
1237
1238           shell> mysqldump --all-databases --master-data --single-transaction > all_databases.sql
1239
1240       This backup acquires a global read lock on all tables (using FLUSH
1241       TABLES WITH READ LOCK) at the beginning of the dump. As soon as this
1242       lock has been acquired, the binary log coordinates are read and the
1243       lock is released. If long updating statements are running when the
1244       FLUSH statement is issued, the MySQL server may get stalled until those
1245       statements finish. After that, the dump becomes lock free and does not
1246       disturb reads and writes on the tables. If the update statements that
1247       the MySQL server receives are short (in terms of execution time), the
1248       initial lock period should not be noticeable, even with many updates.
1249
1250       For point-in-time recovery (also known as “roll-forward,” when you need
1251       to restore an old backup and replay the changes that happened since
1252       that backup), it is often useful to rotate the binary log (see
1253       Section 5.4.4, “The Binary Log”) or at least know the binary log
1254       coordinates to which the dump corresponds:
1255
1256           shell> mysqldump --all-databases --master-data=2 > all_databases.sql
1257
1258       Or:
1259
1260           shell> mysqldump --all-databases --flush-logs --master-data=2
1261                         > all_databases.sql
1262
1263       The --master-data and --single-transaction options can be used
1264       simultaneously, which provides a convenient way to make an online
1265       backup suitable for use prior to point-in-time recovery if tables are
1266       stored using the InnoDB storage engine.
1267
1268       For more information on making backups, see Section 7.2, “Database
1269       Backup Methods”, and Section 7.3, “Example Backup and Recovery
1270       Strategy”.
1271
1272       ·   To select the effect of --opt except for some features, use the
1273           --skip option for each feature. To disable extended inserts and
1274           memory buffering, use --opt --skip-extended-insert --skip-quick.
1275           (Actually, --skip-extended-insert --skip-quick is sufficient
1276           because --opt is on by default.)
1277
1278       ·   To reverse --opt for all features except index disabling and table
1279           locking, use --skip-opt --disable-keys --lock-tables.
1280       Restrictions
1281
1282       mysqldump does not dump the performance_schema or sys schema by
1283       default. To dump any of these, name them explicitly on the command
1284       line. You can also name them with the --databases option. For
1285       performance_schema, also use the --skip-lock-tables option.
1286
1287       mysqldump does not dump the INFORMATION_SCHEMA schema.
1288
1289       mysqldump does not dump InnoDB CREATE TABLESPACE statements.
1290
1291       mysqldump does not dump the NDB Cluster ndbinfo information database.
1292
1293       mysqldump includes statements to recreate the general_log and
1294       slow_query_log tables for dumps of the mysql database. Log table
1295       contents are not dumped.
1296
1297       If you encounter problems backing up views due to insufficient
1298       privileges, see Section 25.9, “Restrictions on Views” for a workaround.
1299
1301       Copyright © 1997, 2020, Oracle and/or its affiliates.
1302
1303       This documentation is free software; you can redistribute it and/or
1304       modify it only under the terms of the GNU General Public License as
1305       published by the Free Software Foundation; version 2 of the License.
1306
1307       This documentation is distributed in the hope that it will be useful,
1308       but WITHOUT ANY WARRANTY; without even the implied warranty of
1309       MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
1310       General Public License for more details.
1311
1312       You should have received a copy of the GNU General Public License along
1313       with the program; if not, write to the Free Software Foundation, Inc.,
1314       51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA or see
1315       http://www.gnu.org/licenses/.
1316
1317

NOTES

1319        1. MySQL Shell dump utilities
1320           https://dev.mysql.com/doc/mysql-shell/8.0/en/mysql-shell-utilities-dump-instance-schema.html
1321
1322        2. MySQL Shell load dump utilities
1323           https://dev.mysql.com/doc/mysql-shell/8.0/en/mysql-shell-utilities-load-dump.html
1324
1325        3. here
1326           https://dev.mysql.com/doc/mysql-shell/8.0/en/mysql-shell-install.html
1327
1328        4. Downgrade Notes
1329           https://dev.mysql.com/doc/refman/5.7/en/downgrading-to-previous-series.html
1330

SEE ALSO

1332       For more information, please refer to the MySQL Reference Manual, which
1333       may already be installed locally and which is also available online at
1334       http://dev.mysql.com/doc/.
1335

AUTHOR

1337       Oracle Corporation (http://dev.mysql.com/).
1338
1339
1340
1341MySQL 8.0                         11/26/2020                      MYSQLDUMP(1)
Impressum