일 | 월 | 화 | 수 | 목 | 금 | 토 |
---|---|---|---|---|---|---|
1 | 2 | 3 | 4 | |||
5 | 6 | 7 | 8 | 9 | 10 | 11 |
12 | 13 | 14 | 15 | 16 | 17 | 18 |
19 | 20 | 21 | 22 | 23 | 24 | 25 |
26 | 27 | 28 | 29 | 30 | 31 |
- 전처리기
- 약어
- DBMS
- newSQL
- 포인터변수
- Symbol
- OS 커널
- 긴옵션
- TiKV
- DBMS 개발
- 포인터
- UNIX Internals
- Pointer
- 컴퓨터 강좌
- SQLite
- Preprocessor
- go
- FreeBSD
- getopts
- UNIX
- kernel
- Golang
- TiDB
- bash
- 한빛미디어
- 함수포인터
- 커널
- 구조와 원리
- Windows via c/c++
- Programming
- Today
- Total
sonumb
[MySQL] mysqldump 이용해서 백업하기 본문
명령어 옵션들
mysqldump
의 명령어 옵션는 아래와 같다.
$ mysqldump --help
mysqldump Ver 10.13 Distrib 5.7.32, for osx10.15 (x86_64)
Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Dumping structure and contents of MySQL databases and tables.
Usage: mysqldump [OPTIONS] database [tables]
OR mysqldump [OPTIONS] --databases [OPTIONS] DB1 [DB2 DB3...]
OR mysqldump [OPTIONS] --all-databases [OPTIONS]
Default options are read from the following files in the given order:
/etc/my.cnf /etc/mysql/my.cnf /usr/local/Cellar/mysql-client@5.7/5.7.32/etc/my.cnf ~/.my.cnf
The following groups are read: mysqldump client
The following options may be given as the first argument:
--print-defaults Print the program argument list and exit.
--no-defaults Don't read default options from any option file,
except for login file.
--defaults-file=# Only read default options from the given file #.
--defaults-extra-file=# Read this file after the global files are read.
--defaults-group-suffix=#
Also read groups with concat(group, suffix)
--login-path=# Read this path from the login file.
-A, --all-databases Dump all the databases. This will be same as --databases
with all databases selected.
-Y, --all-tablespaces
Dump all the tablespaces.
-y, --no-tablespaces
Do not dump any tablespace information.
--add-drop-database Add a DROP DATABASE before each create.
--add-drop-table Add a DROP TABLE before each create.
(Defaults to on; use --skip-add-drop-table to disable.)
--add-drop-trigger Add a DROP TRIGGER before each create.
--add-locks Add locks around INSERT statements.
(Defaults to on; use --skip-add-locks to disable.)
--allow-keywords Allow creation of column names that are keywords.
--apply-slave-statements
Adds 'STOP SLAVE' prior to 'CHANGE MASTER' and 'START
SLAVE' to bottom of dump.
--bind-address=name IP address to bind to.
--character-sets-dir=name
Directory for character set files.
-i, --comments Write additional information.
(Defaults to on; use --skip-comments to disable.)
--compatible=name Change the dump to be compatible with a given mode. By
default tables are dumped in a format optimized for
MySQL. Legal modes are: ansi, mysql323, mysql40,
postgresql, oracle, mssql, db2, maxdb, no_key_options,
no_table_options, no_field_options. One can use several
modes separated by commas. Note: Requires MySQL server
version 4.1.0 or higher. This option is ignored with
earlier server versions.
--compact Give less verbose output (useful for debugging). Disables
structure comments and header/footer constructs. Enables
options --skip-add-drop-table --skip-add-locks
--skip-comments --skip-disable-keys --skip-set-charset.
-c, --complete-insert
Use complete insert statements.
-C, --compress Use compression in server/client protocol.
-a, --create-options
Include all MySQL specific create options.
(Defaults to on; use --skip-create-options to disable.)
-B, --databases Dump several databases. Note the difference in usage; in
this case no tables are given. All name arguments are
regarded as database names. 'USE db_name;' will be
included in the output.
-#, --debug[=#] This is a non-debug version. Catch this and exit.
--debug-check This is a non-debug version. Catch this and exit.
--debug-info This is a non-debug version. Catch this and exit.
--default-character-set=name
Set the default character set.
--delete-master-logs
Delete logs on master after backup. This automatically
enables --master-data.
-K, --disable-keys '/*!40000 ALTER TABLE tb_name DISABLE KEYS */; and
'/*!40000 ALTER TABLE tb_name ENABLE KEYS */; will be put
in the output.
(Defaults to on; use --skip-disable-keys to disable.)
--dump-slave[=#] This causes the binary log position and filename of the
master to be appended to the dumped data output. Setting
the value to 1, will printit as a CHANGE MASTER command
in the dumped data output; if equal to 2, that command
will be prefixed with a comment symbol. This option will
turn --lock-all-tables on, unless --single-transaction is
specified too (in which case a global read lock is only
taken a short time at the beginning of the dump - don't
forget to read about --single-transaction below). In all
cases any action on logs will happen at the exact moment
of the dump.Option automatically turns --lock-tables off.
-E, --events Dump events.
-e, --extended-insert
Use multiple-row INSERT syntax that include several
VALUES lists.
(Defaults to on; use --skip-extended-insert to disable.)
--fields-terminated-by=name
Fields in the output file are terminated by the given
string.
--fields-enclosed-by=name
Fields in the output file are enclosed by the given
character.
--fields-optionally-enclosed-by=name
Fields in the output file are optionally enclosed by the
given character.
--fields-escaped-by=name
Fields in the output file are escaped by the given
character.
-F, --flush-logs Flush logs file in server before starting dump. Note that
if you dump many databases at once (using the option
--databases= or --all-databases), the logs will be
flushed for each database dumped. The exception is when
using --lock-all-tables or --master-data: in this case
the logs will be flushed only once, corresponding to the
moment all tables are locked. So if you want your dump
and the log flush to happen at the same exact moment you
should use --lock-all-tables or --master-data with
--flush-logs.
--flush-privileges Emit a FLUSH PRIVILEGES statement after dumping the mysql
database. This option should be used any time the dump
contains the mysql database and any other database that
depends on the data in the mysql database for proper
restore.
-f, --force Continue even if we get an SQL error.
-?, --help Display this help message and exit.
--hex-blob Dump binary strings (BINARY, VARBINARY, BLOB) in
hexadecimal format.
-h, --host=name Connect to host.
--ignore-error=name A comma-separated list of error numbers to be ignored if
encountered during dump.
--ignore-table=name Do not dump the specified table. To specify more than one
table to ignore, use the directive multiple times, once
for each table. Each table must be specified with both
database and table names, e.g.,
--ignore-table=database.table.
--include-master-host-port
Adds 'MASTER_HOST=<host>, MASTER_PORT=<port>' to 'CHANGE
MASTER TO..' in dump produced with --dump-slave.
--insert-ignore Insert rows with INSERT IGNORE.
--lines-terminated-by=name
Lines in the output file are terminated by the given
string.
-x, --lock-all-tables
Locks all tables across all databases. This is achieved
by taking a global read lock for the duration of the
whole dump. Automatically turns --single-transaction and
--lock-tables off.
-l, --lock-tables Lock all tables for read.
(Defaults to on; use --skip-lock-tables to disable.)
--log-error=name Append warnings and errors to given file.
--master-data[=#] This causes the binary log position and filename to be
appended to the output. If equal to 1, will print it as a
CHANGE MASTER command; if equal to 2, that command will
be prefixed with a comment symbol. This option will turn
--lock-all-tables on, unless --single-transaction is
specified too (in which case a global read lock is only
taken a short time at the beginning of the dump; don't
forget to read about --single-transaction below). In all
cases, any action on logs will happen at the exact moment
of the dump. Option automatically turns --lock-tables
off.
--max-allowed-packet=#
The maximum packet length to send to or receive from
server.
--net-buffer-length=#
The buffer size for TCP/IP and socket communication.
--no-autocommit Wrap tables with autocommit/commit statements.
-n, --no-create-db Suppress the CREATE DATABASE ... IF EXISTS statement that
normally is output for each dumped database if
--all-databases or --databases is given.
-t, --no-create-info
Don't write table creation info.
-d, --no-data No row information.
-N, --no-set-names Same as --skip-set-charset.
--opt Same as --add-drop-table, --add-locks, --create-options,
--quick, --extended-insert, --lock-tables, --set-charset,
and --disable-keys. Enabled by default, disable with
--skip-opt.
--order-by-primary Sorts each table's rows by primary key, or first unique
key, if such a key exists. Useful when dumping a MyISAM
table to be loaded into an InnoDB table, but will make
the dump itself take considerably longer.
-p, --password[=name]
Password to use when connecting to server. If password is
not given it's solicited on the tty.
-P, --port=# Port number to use for connection.
--protocol=name The protocol to use for connection (tcp, socket, pipe,
memory).
-q, --quick Don't buffer query, dump directly to stdout.
(Defaults to on; use --skip-quick to disable.)
-Q, --quote-names Quote table and column names with backticks (`).
(Defaults to on; use --skip-quote-names to disable.)
--replace Use REPLACE INTO instead of INSERT INTO.
-r, --result-file=name
Direct output to a given file. This option should be used
in systems (e.g., DOS, Windows) that use carriage-return
linefeed pairs (\r\n) to separate text lines. This option
ensures that only a single newline is used.
-R, --routines Dump stored routines (functions and procedures).
--set-charset Add 'SET NAMES default_character_set' to the output.
(Defaults to on; use --skip-set-charset to disable.)
--set-gtid-purged[=name]
Add 'SET @@GLOBAL.GTID_PURGED' to the output. Possible
values for this option are ON, OFF and AUTO. If ON is
used and GTIDs are not enabled on the server, an error is
generated. If OFF is used, this option does nothing. If
AUTO is used and GTIDs are enabled on the server, 'SET
@@GLOBAL.GTID_PURGED' is added to the output. If GTIDs
are disabled, AUTO does nothing. If no value is supplied
then the default (AUTO) value will be considered.
--single-transaction
Creates a consistent snapshot by dumping all tables in a
single transaction. Works ONLY for tables stored in
storage engines which support multiversioning (currently
only InnoDB does); the dump is NOT guaranteed to be
consistent for other storage engines. While a
--single-transaction dump is in process, to ensure a
valid dump file (correct table contents and binary log
position), no other connection should use the following
statements: ALTER TABLE, DROP TABLE, RENAME TABLE,
TRUNCATE TABLE, as consistent snapshot is not isolated
from them. Option automatically turns off --lock-tables.
--dump-date Put a dump date to the end of the output.
(Defaults to on; use --skip-dump-date to disable.)
--skip-opt Disable --opt. Disables --add-drop-table, --add-locks,
--create-options, --quick, --extended-insert,
--lock-tables, --set-charset, and --disable-keys.
-S, --socket=name The socket file to use for connection.
--secure-auth Refuse client connecting to server if it uses old
(pre-4.1.1) protocol. Deprecated. Always TRUE
--ssl-mode=name SSL connection mode.
--ssl Deprecated. Use --ssl-mode instead.
(Defaults to on; use --skip-ssl to disable.)
--ssl-verify-server-cert
Deprecated. Use --ssl-mode=VERIFY_IDENTITY instead.
--ssl-ca=name CA file in PEM format.
--ssl-capath=name CA directory.
--ssl-cert=name X509 cert in PEM format.
--ssl-cipher=name SSL cipher to use.
--ssl-key=name X509 key in PEM format.
--ssl-crl=name Certificate revocation list.
--ssl-crlpath=name Certificate revocation list path.
--tls-version=name TLS version to use, permitted values are: TLSv1, TLSv1.1,
TLSv1.2
--server-public-key-path=name
File path to the server public RSA key in PEM format.
--get-server-public-key
Get server public key
-T, --tab=name Create tab-separated textfile for each table to given
path. (Create .sql and .txt files.) NOTE: This only works
if mysqldump is run on the same machine as the mysqld
server.
--tables Overrides option --databases (-B).
--triggers Dump triggers for each dumped table.
(Defaults to on; use --skip-triggers to disable.)
--tz-utc SET TIME_ZONE='+00:00' at top of dump to allow dumping of
TIMESTAMP data when a server has data in different time
zones or data is being moved between servers with
different time zones.
(Defaults to on; use --skip-tz-utc to disable.)
-u, --user=name User for login if not current user.
-v, --verbose Print info about the various stages.
-V, --version Output version information and exit.
-w, --where=name Dump only selected records. Quotes are mandatory.
-X, --xml Dump a database as well formed XML.
--plugin-dir=name Directory for client-side plugins.
--default-auth=name Default authentication client-side plugin to use.
--enable-cleartext-plugin
Enable/disable the clear text authentication plugin.
Variables (--variable-name=value)
and boolean options {FALSE|TRUE} Value (after reading options)
모든 DB를 덤프하는 것보단...
mysqldump [DB_name [table_names [...]] [<options>[, ...]]
와 같이 DB 이름을 지정하여 사용하는 것이 좋다.
모든 DB를 --all-databases
인자와 함께 덤프를 하고 싶겠지만, mysql
, information_schema
와 같은 시스템 데이터베이스까지 덤프를 하므로 추천하지 않는다.
그렇다면, 시스템 메타정보를 제외해보자
SELECT schema_name
FROM information_schema.schemata
WHERE schema_name NOT IN
('information_schema', 'mysql', 'performance_schema', 'sys' );
으로 받아온 나머지 DB이름을 for문으로 덤프하는 것을 추천한다.
결과는 아래와 같다.
mysql> SELECT schema_name FROM information_schema.schemata where schema_name not in ('information_schema', 'mysql', 'performance_schema', 'sys' );
+-------------+
| schema_name |
+-------------+
| test |
| tpcc |
+-------------+
2 rows in set (0.00 sec)
쉘 스크립트로 백업받기
그렇다면, 쉘에서 받아올 수 있도록 해보자. (아래 mysql
의 -N
옵션은 컬럼 이름을 출력하지 않는 옵션이며, --skip-column-names
와 같다)
$ mysql -N -uroot <<< "SELECT schema_name FROM information_schema.schemata WHERE schema_name NOT IN ('information_schema', 'mysql', 'performance_schema', 'sys' );"
test
tpcc
위의 명령어를 이용하여 출력해보자.
for i in `mysql --skip-column-names -uroot <<< "SELECT schema_name FROM information_schema.schemata WHERE schema_name NOT IN ('information_schema', 'mysql', 'performance_schema', 'sys' );"`;
do
echo "mysqldump $i -uroot > backup_$i.sql" ;
done;
위의 결과물은 아래와 같다.
$ for i in `mysql --skip-column-names -uroot <<< "SELECT schema_name FROM information_schema.schemata WHERE schema_name NOT IN ('information_schema', 'mysql', 'performance_schema', 'sys' );"`;
> do
> echo "mysqldump $i -uroot > backup_$i.sql" ;
> done;
mysqldump test -uroot > backup_test.sql
mysqldump tpcc -uroot > backup_tpcc.sql
$
저장 프로시저, 함수도 포함해서 백업하고 싶다면?
--routines
옵션을 이용하면 된다.
mysqldump DB_name -uroot --routines > bck.sql
스키마만 백업하고 싶다면?
--no-data
옵션을 사용하면 된다.
mysqldump DB_name -uroot DB --no-data > bck_scheme_only.sql
실제로는 ...
blob 컬럼은 잘 구슬려야 한다.
mysqldump 명령어를 쓸땐, --hex-blob
옵션을 무조건 넣어주어야 한다. 이 옵션이 있으면 blob 컬럼의 내용이 hex형태의 문자열로 변환되어 출력된다.
운용하고 있는 DB의 특정 테이블에 blob 필드가 있다면, EOF 문자로 인해 덤프파일이 중간에 끊기게 되며, 데이터를 유실하게 된다.
여태 백업받았던 파일이 깨진 백업일 것이다. 이 백업파일을 이용하여 복구를 할 수 없는 절망적인 상황이 닥친다.(
상상만으로도 끔찍하다
)
따라서, 이를 방지하기 위해 --hex-blob
옵션을 항상 써야 한다. mysqldump
가 기입된 모든 스크립트에 항상 같이 기입한다. 설령 백업대상 DB에서 blob을 사용하는 테이블이 없다고 해도, 항상 기입하라. (blob이 있는 테이블이 언제라도 생성될 수 있다)
패킷사이즈 고려하기
또한, varchar가 많거나, blob, text 컬럼 등이 있다면 dump가 제대로 동작하지 않을 가능성이 크다. 왜냐하면, 소켓을 통해 백업을 건네주는데, 허용된 패킷사이즈가 레코드 혹은 테이블 사이즈에 비해 작기 때문이다. 따라서 --max_allowed_packet=<size>
을 이용하여 백업을 해야한다. (이는 my.cnf 파일에 지정하여 명령어 옵션을 생략할 수 있으나 추천하지 않는다.
아래는 내가 실제로 회사에서 사용하고 있는 백업 스크립트의 일부분이다.
# ... 생략 ...
mysqldump ${MYSQL_DB} \
-u${MYSQL_USER} -p${MYSQL_PASS} \
--max_allowed_packet=512M \
--opt --quote-names --skip-set-charset \
--hex-blob --default-character-set=utf8 \
> $DBFILE_PATH
# ... 생략 ...
--opt
, --quote-names
, --default-character-set=utf8
에 관한 내용은 위애서 찾아보길 바란다.
(이중 --opt
와 --quote-names
는 기본값으로 되어 있다.)