.TH "MYSQLDBCOPY" "1" "May 09, 2012" "1.0.3" "MySQL Utilities" .SH NAME mysqldbcopy \- Copy databases from one MySQL server to another . .nr rst2man-indent-level 0 . .de1 rstReportMargin \\$1 \\n[an-margin] level \\n[rst2man-indent-level] level margin: \\n[rst2man-indent\\n[rst2man-indent-level]] - \\n[rst2man-indent0] \\n[rst2man-indent1] \\n[rst2man-indent2] .. .de1 INDENT .\" .rstReportMargin pre: . RS \\$1 . nr rst2man-indent\\n[rst2man-indent-level] \\n[an-margin] . nr rst2man-indent-level +1 .\" .rstReportMargin post: .. .de UNINDENT . RE .\" indent \\n[an-margin] .\" old: \\n[rst2man-indent\\n[rst2man-indent-level]] .nr rst2man-indent-level -1 .\" new: \\n[rst2man-indent\\n[rst2man-indent-level]] .in \\n[rst2man-indent\\n[rst2man-indent-level]]u .. .\" Man page generated from reStructeredText. . .SH SYNOPSIS .sp .nf .ft C mysqldbcopy [options] db_name[:new_db_name] .ft P .fi .SH DESCRIPTION .sp This utility copies a database on a source server to a database on a destination server. If the source and destination servers are different, the database names can be the same or different. If the source and destination servers are the same, the database names must be different. .sp The utility accepts one or more database pairs on the command line. To name a database pair, use \fIdb_name\fP:\fInew_db_name\fP syntax to specify the source and destination names explicitly. If the source and destination database names are the same, \fIdb_name\fP can be used as shorthand for \fIdb_name\fP:\fIdb_name\fP. .sp By default, the operation copies all objects (tables, views, triggers, events, procedures, functions, and database\-level grants) and data to the destination server. There are options to turn off copying any or all of the objects as well as not copying the data. .sp To exclude specific objects by name, use the \fI\-\-exclude\fP option with a name in \fIdb\fP.*obj* format, or you can supply a search pattern. For example, \fI\-\-exclude=db1.trig1\fP excludes the single trigger and \fI\-\-exclude=trig_\fP excludes all objects from all databases having a name that begins with \fBtrig\fP and has a following character. .sp By default, the utility creates each table on the destination server using the same storage engine as the original table. To override this and specify the storage engine to use for all tables created on the destination server, use the \fI\-\-new\-storage\-engine\fP option. If the destination server supports the new engine, all tables use that engine. .sp To specify the storage engine to use for tables for which the destination server does not support the original storage engine on the source server, use the \fI\-\-default\-storage\-engine\fP option. .sp The \fI\-\-new\-storage\-engine\fP option takes precedence over \fI\-\-default\-storage\-engine\fP if both are given. .sp If the \fI\-\-new\-storage\-engine\fP or \fI\-\-default\-storage\-engine\fP option is given and the destination server does not support the specified storage engine, a warning is issued and the server\(aqs default storage engine setting is used instead. .sp By default, the operation uses a consistent snapshot to read the source databases. To change the locking mode, use the \fI\-\-locking\fP option with a locking type value. Use a value of \fBno\-locks\fP to turn off locking altogether or \fBlock\-all\fP to use only table locks. The default value is \fBsnapshot\fP. Additionally, the utility uses WRITE locks to lock the destination tables during the copy. .sp You can include replication statements for copying data among a master and slave or between slaves. The \fI\-\-rpl\fP option permits you to select from the following replication statements to include in the export. .INDENT 0.0 .TP .B \fBmaster\fP Include the \fBCHANGE MASTER\fP statement to start a new slave with the current server acting as the master. This executes the appropriate STOP and START slave statements. The \fBSTOP SLAVE\fP statement is executed at the start of the copy and the \fBCHANGE MASTER\fP followed by the \fBSTART SLAVE\fP statements are executed after the copy. .TP .B \fBslave\fP Include the \fBCHANGE MASTER\fP statement to start a new slave using the current server\(aqs master information. This executes the appropriate STOP and START slave statements. The STOP SLAVE statement is executed at the start of the copy and the \fBCHANGE MASTER\fP followed by the \fBSTART SLAVE\fP statements follow the copy. .UNINDENT .sp To include the replication user in the \fBCHANGE MASTER\fP statement, use the \fI\-\-rpl\-user\fP option to specify the user and password. If this option is omitted, the utility attempts to identify the replication user. In the event that there are multiple candidates or the user requires a password, the utility aborts with an error. .SH OPTIONS .sp \fBmysqldbcopy\fP accepts the following command\-line options: .INDENT 0.0 .TP .B \-\-help Display a help message and exit. .UNINDENT .INDENT 0.0 .TP .B \-\-default\-storage\-engine= The engine to use for tables if the destination server does not support the original storage engine on the source server. .UNINDENT .INDENT 0.0 .TP .B \-\-destination= Connection information for the destination server in <\fIuser\fP>[:<\fIpasswd\fP>]@<\fIhost\fP>[:<\fIport\fP>][:<\fIsocket\fP>] format, where is optional and either or must be provided. .UNINDENT .INDENT 0.0 .TP .B \-\-exclude=, \-x Exclude one or more objects from the operation using either a specific name such as db1.t1 or a search pattern. Use this option multiple times to specify multiple exclusions. By default, patterns use \fBLIKE\fP matching. With the \fI\-\-regexp\fP option, patterns use \fBREGEXP\fP matching. .sp This option does not apply to grants. .UNINDENT .INDENT 0.0 .TP .B \-\-force Drop each database to be copied if exists before copying anything into it. Without this option, an error occurs if you attempt to copy objects into an existing database. .UNINDENT .INDENT 0.0 .TP .B \-\-locking= Choose the lock type for the operation. Permitted lock values are \fBno\-locks\fP (do not use any table locks), \fBlock\-all\fP (use table locks but no transaction and no consistent read), and \fBsnaphot\fP (consistent read using a single transaction). The default is \fBsnapshot\fP. .UNINDENT .INDENT 0.0 .TP .B \-\-new\-storage\-engine= The engine to use for all tables created on the destination server. .UNINDENT .INDENT 0.0 .TP .B \-\-quiet, \-q Turn off all messages for quiet execution. .UNINDENT .INDENT 0.0 .TP .B \-\-regexp, \-\-basic\-regexp, \-G Perform pattern matches using the \fBREGEXP\fP operator. The default is to use \fBLIKE\fP for matching. .UNINDENT .INDENT 0.0 .TP .B \-\-rpl=, \-\-replication= Include replication information. Permitted values are \fBmaster\fP (include the \fBCHANGE MASTER\fP statement using the source server as the master), \fBslave\fP (include the \fBCHANGE MASTER\fP statement using the destination server\(aqs master information), and \fBboth\fP (include the \fBmaster\fP and \fBslave\fP options where applicable). .UNINDENT .INDENT 0.0 .TP .B \-\-rpl\-user= The user and password for the replication user requirement \- e.g. rpl:passwd \- default = rpl:rpl. .UNINDENT .INDENT 0.0 .TP .B \-\-skip= Specify objects to skip in the operation as a comma\-separated list (no spaces). Permitted values are \fBCREATE_DB\fP, \fBDATA\fP, \fBEVENTS\fP, \fBFUNCTIONS\fP, \fBGRANTS\fP, \fBPROCEDURES\fP, \fBTABLES\fP, \fBTRIGGERS\fP, and \fBVIEWS\fP. .UNINDENT .INDENT 0.0 .TP .B \-\-source= Connection information for the source server in <\fIuser\fP>[:<\fIpasswd\fP>]@<\fIhost\fP>[:<\fIport\fP>][:<\fIsocket\fP>] format, where is optional and either or must be provided. .UNINDENT .INDENT 0.0 .TP .B \-\-threads Use multiple threads for cross\-server copy. The default is 1. .UNINDENT .INDENT 0.0 .TP .B \-\-verbose, \-v Specify how much information to display. Use this option multiple times to increase the amount of information. For example, \fI\-v\fP = verbose, \fI\-vv\fP = more verbose, \fI\-vvv\fP = debug. .UNINDENT .INDENT 0.0 .TP .B \-\-version Display version information and exit. .UNINDENT .SH NOTES .sp You must provide connection parameters (user, host, password, and so forth) for an account that has the appropriate privileges to access all objects in the operation. .sp To copy all objects from a source, the user must have these privileges: \fBSELECT\fP and \fBSHOW VIEW\fP for the database, and \fBSELECT\fP for the \fBmysql\fP database. .sp To copy all objects to a destination, the user must have these privileges: \fBCREATE\fP for the database, \fBSUPER\fP (when binary logging is enabled) for procedures and functions, and \fBGRANT OPTION\fP to copy grants. .sp Actual privileges required may differ from installation to installation depending on the security privileges present and whether the database contains certain objects such as views or events and whether binary logging is enabled. .sp The \fI\-\-new\-storage\-engine\fP and \fI\-\-default\-storage\-engine\fP options apply to all destination tables in the operation. .sp Some option combinations may result in errors during the operation. For example, eliminating tables but not views may result in an error a the view is copied. .sp The \fI\-\-rpl\fP option is not valid for copying databases on the same server. An error will be generated. .SH EXAMPLES .sp The following example demonstrates how to use the utility to copy a database named \fButil_test\fP to a new database named \fButil_test_copy\fP on the same server: .sp .nf .ft C $ mysqldbcopy \e \-\-source=root:pass@localhost:3310:/test123/mysql.sock \e \-\-destination=root:pass@localhost:3310:/test123/mysql.sock \e util_test:util_test_copy # Source on localhost: ... connected. # Destination on localhost: ... connected. # Copying database util_test renamed as util_test_copy # Copying TABLE util_test.t1 # Copying table data. # Copying TABLE util_test.t2 # Copying table data. # Copying TABLE util_test.t3 # Copying table data. # Copying TABLE util_test.t4 # Copying table data. # Copying VIEW util_test.v1 # Copying TRIGGER util_test.trg # Copying PROCEDURE util_test.p1 # Copying FUNCTION util_test.f1 # Copying EVENT util_test.e1 # Copying GRANTS from util_test #...done. .ft P .fi .sp If the database to be copied does not contain only InnoDB tables and you want to ensure data integrity of the copied data by locking the tables during the read step, add a \fI\-\-locking=lock\-all\fP option to the command: .sp .nf .ft C $ mysqldbcopy \e \-\-source=root:pass@localhost:3310:/test123/mysql.sock \e \-\-destination=root:pass@localhost:3310:/test123/mysql.sock \e util_test:util_test_copy \-\-locking=lock\-all # Source on localhost: ... connected. # Destination on localhost: ... connected. # Copying database util_test renamed as util_test_copy # Copying TABLE util_test.t1 # Copying table data. # Copying TABLE util_test.t2 # Copying table data. # Copying TABLE util_test.t3 # Copying table data. # Copying TABLE util_test.t4 # Copying table data. # Copying VIEW util_test.v1 # Copying TRIGGER util_test.trg # Copying PROCEDURE util_test.p1 # Copying FUNCTION util_test.f1 # Copying EVENT util_test.e1 # Copying GRANTS from util_test #...done. .ft P .fi .sp To copy one or more databases from a master to a slave, you can use the following command to copy the databases. Use the master as the source and the slave as the destination: .sp .nf .ft C $ mysqldbcopy \-\-source=root@localhost:3310 \e \-\-destination=root@localhost:3311 test123 \-\-rpl=master \e \-\-rpl\-user=rpl # Source on localhost: ... connected. # Destination on localhost: ... connected. # Source on localhost: ... connected. # Stopping slave # Copying database test123 # Copying TABLE test123.t1 # Copying data for TABLE test123.t1 # Connecting to the current server as master # Starting slave #...done. .ft P .fi .sp To copy a database from one slave to another attached to the same master, you can use the following command using the slave with the database to be copied as the source and the slave where the database needs to copied to as the destination: .sp .nf .ft C $ mysqldbcopy \-\-source=root@localhost:3311 \e \-\-destination=root@localhost:3312 test123 \-\-rpl=slave \e \-\-rpl\-user=rpl # Source on localhost: ... connected. # Destination on localhost: ... connected. # Source on localhost: ... connected. # Stopping slave # Copying database test123 # Copying TABLE test123.t1 # Copying data for TABLE test123.t1 # Connecting to the current server\(aqs master # Starting slave #...done. .ft P .fi .SH COPYRIGHT .sp Copyright (c) 2010, 2012, Oracle and/or its affiliates. All rights reserved. .sp This program is free software; you can redistribute it and/or modify it under the terms of the GNU General Public License as published by the Free Software Foundation; version 2 of the License. .sp This program is distributed in the hope that it will be useful, but WITHOUT ANY WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU General Public License for more details. .sp You should have received a copy of the GNU General Public License along with this program; if not, write to the Free Software Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110\-1301 USA .SH AUTHOR MySQL Utilities Team .SH COPYRIGHT 2010, Oracle and/or its affiliates. All rights reserved. .\" Generated by docutils manpage writer. .\" .