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