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

NAME

6       mysqldump - a database backup program
7

SYNOPSIS

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

DESCRIPTION

12       The mysqldump client is a backup program originally written by Igor
13       Romanenko. It can be used to dump a database or a collection of
14       databases for backup or transfer to another SQL server (not necessarily
15       a MySQL server). The dump typically contains SQL statements to create
16       the table, populate it, or both. However, mysqldump can also be used to
17       generate files in CSV, other delimited text, or XML format.
18
19       If you are doing a backup on the server and your tables all are MyISAM
20       tables, consider using the mysqlhotcopy instead because it can
21       accomplish faster backups and faster restores. See mysqlhotcopy(1).
22
23       There are three general ways to invoke mysqldump:
24
25           shell> mysqldump [options] db_name [tbl_name ...]
26           shell> mysqldump [options] --databases db_name ...
27           shell> mysqldump [options] --all-databases
28
29       If you do not name any tables following db_name or if you use the
30       --databases or --all-databases option, entire databases are dumped.
31
32       mysqldump does not dump the INFORMATION_SCHEMA database by default. As
33       of MySQL 5.1.38, mysqldump dumps INFORMATION_SCHEMA if you name it
34       explicitly on the command line, although currently you must also use
35       the --skip-lock-tables option. Before 5.1.38, mysqldump silently
36       ignores INFORMATION_SCHEMA even if you name it explicitly on the
37       command line.
38
39       To see a list of the options your version of mysqldump supports,
40       execute mysqldump --help.
41
42       Some mysqldump options are shorthand for groups of other options:
43
44       ·   Use of --opt is the same as specifying --add-drop-table,
45           --add-locks, --create-options, --disable-keys, --extended-insert,
46           --lock-tables, --quick, and --set-charset. All of the options that
47           --opt stands for also are on by default because --opt is on by
48           default.
49
50       ·   Use of --compact is the same as specifying --skip-add-drop-table,
51           --skip-add-locks, --skip-comments, --skip-disable-keys, and
52           --skip-set-charset options.
53
54       To reverse the effect of a group option, uses its --skip-xxx form
55       (--skip-opt or --skip-compact). It is also possible to select only part
56       of the effect of a group option by following it with options that
57       enable or disable specific features. Here are some examples:
58
59       ·   To select the effect of --opt except for some features, use the
60           --skip option for each feature. To disable extended inserts and
61           memory buffering, use --opt --skip-extended-insert --skip-quick.
62           (Actually, --skip-extended-insert --skip-quick is sufficient
63           because --opt is on by default.)
64
65       ·   To reverse --opt for all features except index disabling and table
66           locking, use --skip-opt --disable-keys --lock-tables.
67
68       When you selectively enable or disable the effect of a group option,
69       order is important because options are processed first to last. For
70       example, --disable-keys --lock-tables --skip-opt would not have the
71       intended effect; it is the same as --skip-opt by itself.
72
73       mysqldump can retrieve and dump table contents row by row, or it can
74       retrieve the entire content from a table and buffer it in memory before
75       dumping it. Buffering in memory can be a problem if you are dumping
76       large tables. To dump tables row by row, use the --quick option (or
77       --opt, which enables --quick). The --opt option (and hence --quick) is
78       enabled by default, so to enable memory buffering, use --skip-quick.
79
80       If you are using a recent version of mysqldump to generate a dump to be
81       reloaded into a very old MySQL server, you should not use the --opt or
82       --extended-insert option. Use --skip-opt instead.
83
84           Note
85           mysqldump from MySQL 5.1.21 cannot be used to create dumps from
86           MySQL server 5.1.20 and older. This issue is fixed in MySQL 5.1.22.
87           (Bug#30123[1])
88
89       mysqldump supports the following options, which can be specified on the
90       command line or in the [mysqldump] and [client] option file groups.
91       mysqldump also supports the options for processing option files
92       described at Section 4.2.3.3.1, “Command-Line Options that Affect
93       Option-File Handling”.
94
95       ·   --help, -?
96
97           Display a help message and exit.
98
99       ·   --add-drop-database
100
101           Add a DROP DATABASE statement before each CREATE DATABASE
102           statement. This option is typically used in conjunction with the
103           --all-databases or --databases option because no CREATE DATABASE
104           statements are written unless one of those options is specified.
105
106       ·   --add-drop-table
107
108           Add a DROP TABLE statement before each CREATE TABLE statement.
109
110       ·   --add-locks
111
112           Surround each table dump with LOCK TABLES and UNLOCK TABLES
113           statements. This results in faster inserts when the dump file is
114           reloaded. See Section 7.2.21, “Speed of INSERT Statements”.
115
116       ·   --all-databases, -A
117
118           Dump all tables in all databases. This is the same as using the
119           --databases option and naming all the databases on the command
120           line.
121
122       ·   --all-tablespaces, -Y
123
124           Adds to a table dump all SQL statements needed to create any
125           tablespaces used by an NDBCLUSTER table. This information is not
126           otherwise included in the output from mysqldump. This option is
127           currently relevant only to MySQL Cluster tables.
128
129           This option was added in MySQL 5.1.6.
130
131       ·   --allow-keywords
132
133           Allow creation of column names that are keywords. This works by
134           prefixing each column name with the table name.
135
136       ·   --character-sets-dir=path
137
138           The directory where character sets are installed. See Section 9.5,
139           “Character Set Configuration”.
140
141       ·   --comments, -i
142
143           Write additional information in the dump file such as program
144           version, server version, and host. This option is enabled by
145           default. To suppress this additional information, use
146           --skip-comments.
147
148       ·   --compact
149
150           Produce more compact output. This option enables the
151           --skip-add-drop-table, --skip-add-locks, --skip-comments,
152           --skip-disable-keys, and --skip-set-charset options.
153
154               Note
155               Prior to MySQL 5.1.21, this option did not create valid SQL if
156               the database dump contained views. The recreation of views
157               requires the creation and removal of temporary tables and this
158               option suppressed the removal of those temporary tables. As a
159               workaround, use --compact with the --add-drop-table option and
160               then manually adjust the dump file.
161
162       ·   --compatible=name
163
164           Produce output that is more compatible with other database systems
165           or with older MySQL servers. The value of name can be ansi,
166           mysql323, mysql40, postgresql, oracle, mssql, db2, maxdb,
167           no_key_options, no_table_options, or no_field_options. To use
168           several values, separate them by commas. These values have the same
169           meaning as the corresponding options for setting the server SQL
170           mode. See Section 5.1.8, “Server SQL Modes”.
171
172           This option does not guarantee compatibility with other servers. It
173           only enables those SQL mode values that are currently available for
174           making dump output more compatible. For example,
175           --compatible=oracle does not map data types to Oracle types or use
176           Oracle comment syntax.
177
178           This option requires a server version of 4.1.0 or higher. With
179           older servers, it does nothing.
180
181       ·   --complete-insert, -c
182
183           Use complete INSERT statements that include column names.
184
185       ·   --compress, -C
186
187           Compress all information sent between the client and the server if
188           both support compression.
189
190       ·   --create-options, -a
191
192           Include all MySQL-specific table options in the CREATE TABLE
193           statements.
194
195       ·   --databases, -B
196
197           Dump several databases. Normally, mysqldump treats the first name
198           argument on the command line as a database name and following names
199           as table names. With this option, it treats all name arguments as
200           database names.  CREATE DATABASE and USE statements are included in
201           the output before each new database.
202
203       ·   --debug[=debug_options], -# [debug_options]
204
205           Write a debugging log. A typical debug_options string is
206           ´d:t:o,file_name´. The default value is
207           ´d:t:o,/tmp/mysqldump.trace´.
208
209       ·   --debug-check
210
211           Print some debugging information when the program exits. This
212           option was added in MySQL 5.1.21.
213
214       ·   --debug-info
215
216           Print debugging information and memory and CPU usage statistics
217           when the program exits. This option was added in MySQL 5.1.14.
218
219       ·   --default-character-set=charset_name
220
221           Use charset_name as the default character set. See Section 9.5,
222           “Character Set Configuration”. If no character set is specified,
223           mysqldump uses utf8, and earlier versions use latin1.
224
225           Prior to MySQL 5.1.38, this option has no effect for output data
226           files produced by using the --tab option. See the description for
227           that option.
228
229       ·   --defaults-extra-file=filename
230
231           Set filename as the file to read default options from after the
232           global defaults files has been read.  Must be given as first
233           option.
234
235       ·   --defaults-file=filename
236
237           Set filename as the file to read default options from, override
238           global defaults files.  Must be given as first option.
239
240       ·   --delayed-insert
241
242           Write INSERT DELAYED statements rather than INSERT statements.
243
244       ·   --delete-master-logs
245
246           On a master replication server, delete the binary logs by sending a
247           PURGE BINARY LOGS statement to the server after performing the dump
248           operation. This option automatically enables --master-data.
249
250       ·   --disable-keys, -K
251
252           For each table, surround the INSERT statements with /*!40000 ALTER
253           TABLE tbl_name DISABLE KEYS */; and /*!40000 ALTER TABLE tbl_name
254           ENABLE KEYS */; statements. This makes loading the dump file faster
255           because the indexes are created after all rows are inserted. This
256           option is effective only for nonunique indexes of MyISAM tables.
257
258       ·   --dump-date
259
260           If the --comments option is given, mysqldump produces a comment at
261           the end of the dump of the following form:
262
263               -- Dump completed on DATE
264
265           However, the date causes dump files taken at different times to
266           appear to be different, even if the data are otherwise identical.
267           --dump-date and --skip-dump-date control whether the date is added
268           to the comment. The default is --dump-date (include the date in the
269           comment).  --skip-dump-date suppresses date printing. This option
270           was added in MySQL 5.1.23.
271
272       ·   --events, -E
273
274           Include Event Scheduler events for the dumped databases in the
275           output. This option was added in MySQL 5.1.8.
276
277       ·   --extended-insert, -e
278
279           Use multiple-row INSERT syntax that include several VALUES lists.
280           This results in a smaller dump file and speeds up inserts when the
281           file is reloaded.
282
283       ·   --fields-terminated-by=..., --fields-enclosed-by=...,
284           --fields-optionally-enclosed-by=..., --fields-escaped-by=...
285
286           These options are used with the --tab option and have the same
287           meaning as the corresponding FIELDS clauses for LOAD DATA INFILE.
288           See Section 12.2.6, “LOAD DATA INFILE Syntax”.
289
290       ·   --first-slave
291
292           Deprecated. Use --lock-all-tables instead.  --first-slave is
293           removed in MySQL 5.5.
294
295       ·   --flush-logs, -F
296
297           Flush the MySQL server log files before starting the dump. This
298           option requires the RELOAD privilege. If you use this option in
299           combination with the --all-databases option, the logs are flushed
300           for each database dumped. The exception is when using
301           --lock-all-tables or --master-data: In this case, the logs are
302           flushed only once, corresponding to the moment that all tables are
303           locked. If you want your dump and the log flush to happen at
304           exactly the same moment, you should use --flush-logs together with
305           either --lock-all-tables or --master-data.
306
307       ·   --flush-privileges
308
309           Send a FLUSH PRIVILEGES statement to the server after dumping the
310           mysql database. This option should be used any time the dump
311           contains the mysql database and any other database that depends on
312           the data in the mysql database for proper restoration. This option
313           was added in MySQL 5.1.12.
314
315       ·   --force, -f
316
317           Continue even if an SQL error occurs during a table dump.
318
319           One use for this option is to cause mysqldump to continue executing
320           even when it encounters a view that has become invalid because the
321           definition refers to a table that has been dropped. Without
322           --force, mysqldump exits with an error message. With --force,
323           mysqldump prints the error message, but it also writes an SQL
324           comment containing the view definition to the dump output and
325           continues executing.
326
327       ·   --host=host_name, -h host_name
328
329           Dump data from the MySQL server on the given host. The default host
330           is localhost.
331
332       ·   --hex-blob
333
334           Dump binary columns using hexadecimal notation (for example, ´abc´
335           becomes 0x616263). The affected data types are BINARY, VARBINARY,
336           the BLOB types, and BIT.
337
338       ·   --ignore-table=db_name.tbl_name
339
340           Do not dump the given table, which must be specified using both the
341           database and table names. To ignore multiple tables, use this
342           option multiple times. This option also can be used to ignore
343           views.
344
345       ·   --insert-ignore
346
347           Write INSERT IGNORE statements rather than INSERT statements.
348
349       ·   --lines-terminated-by=...
350
351           This option is used with the --tab option and has the same meaning
352           as the corresponding LINES clause for LOAD DATA INFILE. See
353           Section 12.2.6, “LOAD DATA INFILE Syntax”.
354
355       ·   --lock-all-tables, -x
356
357           Lock all tables across all databases. This is achieved by acquiring
358           a global read lock for the duration of the whole dump. This option
359           automatically turns off --single-transaction and --lock-tables.
360
361       ·   --lock-tables, -l
362
363           For each dumped database, lock all tables to be dumped before
364           dumping them. The tables are locked with READ LOCAL to allow
365           concurrent inserts in the case of MyISAM tables. For transactional
366           tables such as InnoDB, --single-transaction is a much better option
367           than --lock-tables because it does not need to lock the tables at
368           all.
369
370           Because --lock-tables locks tables for each database separately,
371           this option does not guarantee that the tables in the dump file are
372           logically consistent between databases. Tables in different
373           databases may be dumped in completely different states.
374
375       ·   --log-error=file_name
376
377           Log warnings and errors by appending them to the named file. The
378           default is to do no logging. This option was added in MySQL 5.1.18.
379
380       ·   --master-data[=value]
381
382           Use this option to dump a master replication server to produce a
383           dump file that can be used to set up another server as a slave of
384           the master. It causes the dump output to include a CHANGE MASTER TO
385           statement that indicates the binary log coordinates (file name and
386           position) of the dumped server. These are the master server
387           coordinates from which the slave should start replicating after you
388           load the dump file into the slave.
389
390           If the option value is 2, the CHANGE MASTER TO statement is written
391           as an SQL comment, and thus is informative only; it has no effect
392           when the dump file is reloaded. If the option value is 1, the
393           statement is not written as a comment and takes effect when the
394           dump file is reloaded. If no option value is specified, the default
395           value is 1.
396
397           This option requires the RELOAD privilege and the binary log must
398           be enabled.
399
400           The --master-data option automatically turns off --lock-tables. It
401           also turns on --lock-all-tables, unless --single-transaction also
402           is specified, in which case, a global read lock is acquired only
403           for a short time at the beginning of the dump (see the description
404           for --single-transaction). In all cases, any action on logs happens
405           at the exact moment of the dump.
406
407           It is also possible to set up a slave by dumping an existing slave
408           of the master. To do this, use the following procedure on the
409           existing slave:
410
411            1. Stop the slave´s SQL thread and get its current status:
412
413                   mysql> STOP SLAVE SQL_THREAD;
414                   mysql> SHOW SLAVE STATUS;
415
416            2. From the output of the SHOW SLAVE STATUS statement, the binary
417               log coordinates of the master server from which the new slave
418               should start replicating are the values of the
419               Relay_Master_Log_File and Exec_Master_Log_Pos fields. Denote
420               those values as file_name and file_pos.
421
422            3. Dump the slave server:
423
424                   shell> mysqldump --master-data=2 --all-databases > dumpfile
425
426            4. Restart the slave:
427
428                   mysql> START SLAVE;
429
430            5. On the new slave, load the dump file:
431
432                   shell> mysql < dumpfile
433
434            6. On the new slave, set the replication coordinates to those of
435               the master server obtained earlier:
436
437                   mysql> CHANGE MASTER TO
438                       -> MASTER_LOG_FILE = ´file_name´, MASTER_LOG_POS = file_pos;
439
440               The CHANGE MASTER TO statement might also need other
441               parameters, such as MASTER_HOST to point the slave to the
442               correct master server host. Add any such parameters as
443               necessary.
444
445       ·   --max-allowed-packet=length
446
447           Sets the maximum packet length to send to or recieve from server.
448
449       ·   --net-buffer-length=length
450
451           Sets the buffer size for TCP/IP and socket communication.
452
453       ·   --no-autocommit
454
455           Enclose the INSERT statements for each dumped table within SET
456           autocommit = 0 and COMMIT statements.
457
458       ·   --no-create-db, -n
459
460           This option suppresses the CREATE DATABASE statements that are
461           otherwise included in the output if the --databases or
462           --all-databases option is given.
463
464       ·   --no-create-info, -t
465
466           Do not write CREATE TABLE statements that re-create each dumped
467           table.
468
469       ·   --no-data, -d
470
471           Do not write any table row information (that is, do not dump table
472           contents). This is useful if you want to dump only the CREATE TABLE
473           statement for the table (for example, to create an empty copy of
474           the table by loading the dump file).
475
476       ·   --no-defaults
477
478           Do not read default options from any option file. This must be
479           given as the first argument.
480
481       ·   --no-set-names, -N
482
483           This has the same effect as --skip-set-charset.
484
485       ·   --opt
486
487           This option is shorthand. It is the same as specifying
488           --add-drop-table --add-locks --create-options --disable-keys
489           --extended-insert --lock-tables --quick --set-charset. It should
490           give you a fast dump operation and produce a dump file that can be
491           reloaded into a MySQL server quickly.
492
493           The --opt option is enabled by default. Use --skip-opt to disable
494           it.  See the discussion at the beginning of this section for
495           information about selectively enabling or disabling a subset of the
496           options affected by --opt.
497
498       ·   --order-by-primary
499
500           Dump each table´s rows sorted by its primary key, or by its first
501           unique index, if such an index exists. This is useful when dumping
502           a MyISAM table to be loaded into an InnoDB table, but will make the
503           dump operation take considerably longer.
504
505       ·   --password[=password], -p[password]
506
507           The password to use when connecting to the server. If you use the
508           short option form (-p), you cannot have a space between the option
509           and the password. If you omit the password value following the
510           --password or -p option on the command line, mysqldump prompts for
511           one.
512
513           Specifying a password on the command line should be considered
514           insecure. See Section 5.3.2.2, “End-User Guidelines for Password
515           Security”. You can use an option file to avoid giving the password
516           on the command line.
517
518       ·   --pipe, -W
519
520           On Windows, connect to the server via a named pipe. This option
521           applies only if the server supports named-pipe connections.
522
523       ·   --port=port_num, -P port_num
524
525           The TCP/IP port number to use for the connection.
526
527       ·   --protocol={TCP|SOCKET|PIPE|MEMORY}
528
529           The connection protocol to use for connecting to the server. It is
530           useful when the other connection parameters normally would cause a
531           protocol to be used other than the one you want. For details on the
532           allowable values, see Section 4.2.2, “Connecting to the MySQL
533           Server”.
534
535       ·   --quick, -q
536
537           This option is useful for dumping large tables. It forces mysqldump
538           to retrieve rows for a table from the server a row at a time rather
539           than retrieving the entire row set and buffering it in memory
540           before writing it out.
541
542       ·   --print-defaults
543
544           Print the program argument list and exit. This must begiven as the
545           first argument.
546
547       ·   --quote-names, -Q
548
549           Quote identifiers (such as database, table, and column names)
550           within “`” characters. If the ANSI_QUOTES SQL mode is enabled,
551           identifiers are quoted within “"” characters. This option is
552           enabled by default. It can be disabled with --skip-quote-names, but
553           this option should be given after any option such as --compatible
554           that may enable --quote-names.
555
556       ·   --replace
557
558           Write REPLACE statements rather than INSERT statements. This option
559           was added in MySQL 5.1.3.
560
561       ·   --result-file=file_name, -r file_name
562
563           Direct output to a given file. This option should be used on
564           Windows to prevent newline “\n” characters from being converted to
565           “\r\n” carriage return/newline sequences. The result file is
566           created and its previous contents overwritten, even if an error
567           occurs while generating the dump.
568
569       ·   --routines, -R
570
571           Included stored routines (procedures and functions) for the dumped
572           databases in the output. Use of this option requires the SELECT
573           privilege for the mysql.proc table. The output generated by using
574           --routines contains CREATE PROCEDURE and CREATE FUNCTION statements
575           to re-create the routines. However, these statements do not include
576           attributes such as the routine creation and modification
577           timestamps. This means that when the routines are reloaded, they
578           will be created with the timestamps equal to the reload time.
579
580           If you require routines to be re-created with their original
581           timestamp attributes, do not use --routines. Instead, dump and
582           reload the contents of the mysql.proc table directly, using a MySQL
583           account that has appropriate privileges for the mysql database.
584
585           This option was added in MySQL 5.1.2. Before that, stored routines
586           are not dumped. Routine DEFINER values are not dumped until MySQL
587           5.1.8. This means that before 5.1.8, when routines are reloaded,
588           they will be created with the definer set to the reloading user. If
589           you require routines to be re-created with their original definer,
590           dump and load the contents of the mysql.proc table directly as
591           described earlier.
592
593       ·   --set-charset
594
595           Add SET NAMES default_character_set to the output. This option is
596           enabled by default. To suppress the SET NAMES statement, use
597           --skip-set-charset.
598
599       ·   --single-transaction
600
601           This option sends a START TRANSACTION SQL statement to the server
602           before dumping data. It is useful only with transactional tables
603           such as InnoDB, because then it dumps the consistent state of the
604           database at the time when BEGIN was issued without blocking any
605           applications.
606
607           When using this option, you should keep in mind that only InnoDB
608           tables are dumped in a consistent state. For example, any MyISAM or
609           MEMORY tables dumped while using this option may still change
610           state.
611
612           While a --single-transaction dump is in process, to ensure a valid
613           dump file (correct table contents and binary log coordinates), no
614           other connection should use the following statements: ALTER TABLE,
615           CREATE TABLE, DROP TABLE, RENAME TABLE, TRUNCATE TABLE. A
616           consistent read is not isolated from those statements, so use of
617           them on a table to be dumped can cause the SELECT that is performed
618           by mysqldump to retrieve the table contents to obtain incorrect
619           contents or fail.
620
621           The --single-transaction option and the --lock-tables option are
622           mutually exclusive because LOCK TABLES causes any pending
623           transactions to be committed implicitly.
624
625           This option is not supported for MySQL Cluster tables; the results
626           cannot be guaranteed to be consistent due to the fact that the
627           NDBCLUSTER storage engine supports only the READ_COMMITTED
628           transaction isolation level. You should always use NDB backup and
629           restore instead.
630
631           To dump large tables, you should combine the --single-transaction
632           option with --quick.
633
634       ·   --skip-comments
635
636           See the description for the --comments option.
637
638       ·   --skip-opt
639
640           See the description for the --opt option.
641
642       ·   --socket=path, -S path
643
644           For connections to localhost, the Unix socket file to use, or, on
645           Windows, the name of the named pipe to use.
646
647       ·   --ssl*
648
649           Options that begin with --ssl specify whether to connect to the
650           server via SSL and indicate where to find SSL keys and
651           certificates. See Section 5.5.6.3, “SSL Command Options”.
652
653       ·   --tab=path, -T path
654
655           Produce tab-separated text-format data files. For each dumped
656           table, mysqldump creates a tbl_name.sql file that contains the
657           CREATE TABLE statement that creates the table, and the server
658           writes a tbl_name.txt file that contains its data. The option value
659           is the directory in which to write the files.
660
661               Note
662               This option should be used only when mysqldump is run on the
663               same machine as the mysqld server. You must have the FILE
664               privilege, and the server must have permission to write files
665               in the directory that you specify.
666           By default, the .txt data files are formatted using tab characters
667           between column values and a newline at the end of each line. The
668           format can be specified explicitly using the --fields-xxx and
669           --lines-terminated-by options.
670
671           As of MySQL 5.1.38, column values are converted to the character
672           set specified by the --default-character-set option. Prior to
673           5.1.38 or if no such option is present, values are dumped using the
674           binary character set. In effect, there is no character set
675           conversion. If a table contains columns in several character sets,
676           the output data file will as well and you may not be able to reload
677           the file correctly.
678
679       ·   --tables
680
681           Override the --databases or -B option.  mysqldump regards all name
682           arguments following the option as table names.
683
684       ·   --triggers
685
686           Include triggers for each dumped table in the output. This option
687           is enabled by default; disable it with --skip-triggers.
688
689       ·   --tz-utc
690
691           This option enables TIMESTAMP columns to be dumped and reloaded
692           between servers in different time zones.  mysqldump sets its
693           connection time zone to UTC and adds SET TIME_ZONE=´+00:00´ to the
694           dump file. Without this option, TIMESTAMP columns are dumped and
695           reloaded in the time zones local to the source and destination
696           servers, which can cause the values to change if the servers are in
697           different time zones.  --tz-utc also protects against changes due
698           to daylight saving time.  --tz-utc is enabled by default. To
699           disable it, use --skip-tz-utc. This option was added in MySQL
700           5.1.2.
701
702       ·   --user=user_name, -u user_name
703
704           The MySQL user name to use when connecting to the server.
705
706       ·   --verbose, -v
707
708           Verbose mode. Print more information about what the program does.
709
710       ·   --version, -V
711
712           Display version information and exit.
713
714       ·   --where=´where_condition´, -w ´where_condition´
715
716           Dump only rows selected by the given WHERE condition. Quotes around
717           the condition are mandatory if it contains spaces or other
718           characters that are special to your command interpreter.
719
720           Examples:
721
722               --where="user=´jimf´"
723               -w"userid>1"
724               -w"userid<1"
725
726       ·   --xml, -X
727
728           Write dump output as well-formed XML.
729
730           NULL, ´NULL´, and Empty Values: For a column named column_name, the
731           NULL value, an empty string, and the string value ´NULL´ are
732           distinguished from one another in the output generated by this
733           option as follows.
734
735           ┌──────────────────────┬───────────────────────────────────────────┐
736Value:                │ XML Representation:                       │
737           ├──────────────────────┼───────────────────────────────────────────┤
738           │NULL (unknown value)  │ <field name="column_name" xsi:nil="true"  │
739           │                      │ />                                        │
740           ├──────────────────────┼───────────────────────────────────────────┤
741           │´´ (empty string)     │ <field name="column_name"></field>        │
742           ├──────────────────────┼───────────────────────────────────────────┤
743           │´NULL´ (string value) │ <field name="column_name">NULL</field>    │
744           └──────────────────────┴───────────────────────────────────────────┘
745           Beginning with MySQL 5.1.12, the output from the mysql client when
746           run using the --xml option also follows the preceding rules. (See
747           the section called “MYSQL OPTIONS”.)
748
749           Beginning with MySQL 5.1.18, XML output from mysqldump includes the
750           XML namespace, as shown here:
751
752               shell> mysqldump --xml -u root world City
753               <?xml version="1.0"?>
754               <mysqldump xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance">
755               <database name="world">
756               <table_structure name="City">
757               <field Field="ID" Type="int(11)" Null="NO" Key="PRI" Extra="auto_increment" />
758               <field Field="Name" Type="char(35)" Null="NO" Key="" Default="" Extra="" />
759               <field Field="CountryCode" Type="char(3)" Null="NO" Key="" Default="" Extra="" />
760               <field Field="District" Type="char(20)" Null="NO" Key="" Default="" Extra="" />
761               <field Field="Population" Type="int(11)" Null="NO" Key="" Default="0" Extra="" />
762               <key Table="City" Non_unique="0" Key_name="PRIMARY" Seq_in_index="1" Column_name="ID"
763               Collation="A" Cardinality="4079" Null="" Index_type="BTREE" Comment="" />
764               <options Name="City" Engine="MyISAM" Version="10" Row_format="Fixed" Rows="4079"
765               Avg_row_length="67" Data_length="273293" Max_data_length="18858823439613951"
766               Index_length="43008" Data_free="0" Auto_increment="4080"
767               Create_time="2007-03-31 01:47:01" Update_time="2007-03-31 01:47:02"
768               Collation="latin1_swedish_ci" Create_options="" Comment="" />
769               </table_structure>
770               <table_data name="City">
771               <row>
772               <field name="ID">1</field>
773               <field name="Name">Kabul</field>
774               <field name="CountryCode">AFG</field>
775               <field name="District">Kabol</field>
776               <field name="Population">1780000</field>
777               </row>
778               ...
779               <row>
780               <field name="ID">4079</field>
781               <field name="Name">Rafah</field>
782               <field name="CountryCode">PSE</field>
783               <field name="District">Rafah</field>
784               <field name="Population">92020</field>
785               </row>
786               </table_data>
787               </database>
788               </mysqldump>
789
790
791       You can also set the following variables by using --var_name=value
792       syntax:
793
794       ·   max_allowed_packet
795
796           The maximum size of the buffer for client/server communication. The
797           maximum is 1GB.
798
799       ·   net_buffer_length
800
801           The initial size of the buffer for client/server communication.
802           When creating multiple-row INSERT statements (as with the
803           --extended-insert or --opt option), mysqldump creates rows up to
804           net_buffer_length length. If you increase this variable, you should
805           also ensure that the net_buffer_length variable in the MySQL server
806           is at least this large.
807
808       A common use of mysqldump is for making a backup of an entire database:
809
810           shell> mysqldump db_name > backup-file.sql
811
812       You can load the dump file back into the server like this:
813
814           shell> mysql db_name < backup-file.sql
815
816       Or like this:
817
818           shell> mysql -e "source /path-to-backup/backup-file.sql" db_name
819
820       mysqldump is also very useful for populating databases by copying data
821       from one MySQL server to another:
822
823           shell> mysqldump --opt db_name | mysql --host=remote_host -C db_name
824
825       It is possible to dump several databases with one command:
826
827           shell> mysqldump --databases db_name1 [db_name2 ...] > my_databases.sql
828
829       To dump all databases, use the --all-databases option:
830
831           shell> mysqldump --all-databases > all_databases.sql
832
833       For InnoDB tables, mysqldump provides a way of making an online backup:
834
835           shell> mysqldump --all-databases --single-transaction > all_databases.sql
836
837       This backup acquires a global read lock on all tables (using FLUSH
838       TABLES WITH READ LOCK) at the beginning of the dump. As soon as this
839       lock has been acquired, the binary log coordinates are read and the
840       lock is released. If long updating statements are running when the
841       FLUSH statement is issued, the MySQL server may get stalled until those
842       statements finish. After that, the dump becomes lock free and does not
843       disturb reads and writes on the tables. If the update statements that
844       the MySQL server receives are short (in terms of execution time), the
845       initial lock period should not be noticeable, even with many updates.
846
847       For point-in-time recovery (also known as “roll-forward,” when you need
848       to restore an old backup and replay the changes that happened since
849       that backup), it is often useful to rotate the binary log (see
850       Section 5.2.4, “The Binary Log”) or at least know the binary log
851       coordinates to which the dump corresponds:
852
853           shell> mysqldump --all-databases --master-data=2 > all_databases.sql
854
855       Or:
856
857           shell> mysqldump --all-databases --flush-logs --master-data=2
858                         > all_databases.sql
859
860       The --master-data and --single-transaction options can be used
861       simultaneously, which provides a convenient way to make an online
862       backup suitable for use prior to point-in-time recovery if tables are
863       stored using the InnoDB storage engine.
864
865       For more information on making backups, see Section 6.2, “Database
866       Backup Methods”, and Section 6.3, “Example Backup and Recovery
867       Strategy”.
868
869       If you encounter problems backing up views, please read the section
870       that covers restrictions on views which describes a workaround for
871       backing up views when this fails due to insufficient privileges. See
872       Section D.4, “Restrictions on Views”.
873
875       Copyright 2007-2008 MySQL AB, 2008-2010 Sun Microsystems, Inc.
876
877       This documentation is free software; you can redistribute it and/or
878       modify it only under the terms of the GNU General Public License as
879       published by the Free Software Foundation; version 2 of the License.
880
881       This documentation is distributed in the hope that it will be useful,
882       but WITHOUT ANY WARRANTY; without even the implied warranty of
883       MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
884       General Public License for more details.
885
886       You should have received a copy of the GNU General Public License along
887       with the program; if not, write to the Free Software Foundation, Inc.,
888       51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA or see
889       http://www.gnu.org/licenses/.
890
891

NOTES

893        1. Bug#30123
894           http://bugs.mysql.com/bug.php?id=30123
895

SEE ALSO

897       For more information, please refer to the MySQL Reference Manual, which
898       may already be installed locally and which is also available online at
899       http://dev.mysql.com/doc/.
900

AUTHOR

902       Sun Microsystems, Inc. (http://www.mysql.com/).
903
904
905
906MySQL 5.1                         04/06/2010                      MYSQLDUMP(1)
Impressum