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