.TH "MYSQLDBCOMPARE" "1" "May 09, 2012" "1.0.3" "MySQL Utilities" .SH NAME mysqldbcompare \- check two databases and identify any differences . .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 mysqldbcompare [options] db1[:db2] ... .ft P .fi .SH DESCRIPTION .sp This utility compares the objects and data from two databases to find differences. It identifies objects having different definitions in the two databases and presents them in a diff\-style format of choice. Differences in the data are shown using a similar diff\-style format. Changed or missing rows are shown in a standard format of GRID, CSV, TAB, or VERTICAL. .sp Use the notation db1:db2 to name two databases to compare, or, alternatively just db1 to compare two databases with the same name. The latter case is a convenience notation for comparing same\-named databases on different servers. .sp The comparison may be run against two databases of different names on a single server by specifying only the \fI\-\-server1\fP option. The user can also connect to another server by specifying the \fI\-\-server2\fP option. In this case, db1 is taken from server1 and db2 from server2. .sp Those objects considered in the database include tables, views, triggers, procedures, functions, and events. A count for each object type can be shown with the \fI\-vv\fP option. .sp The check is performed using a series of steps called tests. By default, the utility stops on the first failed test, but you can specify the \fI\%--run-all-tests\fP option to cause the utility to run all tests regardless of their end state. .sp Note: Using \fI\%--run-all-tests\fP may produce expected cascade failures. For example, if the row counts differ among two tables being compared, the data consistency will also fail. .sp The tests include the following: .INDENT 0.0 .IP 1. 3 Check database definitions .sp A database existence precondition check ensures that both databases exist. If they do not, no further processing is possible and the \fI\%--run-all-tests\fP option is ignored. .IP 2. 3 Check existence of objects in both databases .sp The test for objects in both databases identifies those objects missing from one or another database. The remaining tests apply only to those objects that appear in both databases. To skip this test, use the \fI\%--skip-object-compare\fP option. That can be useful when there are known missing objects among the databases. .IP 3. 3 Compare object definitions .sp The definitions (the \fBCREATE\fP statements) are compared and differences are presented. To skip this test, use the \fI\%--skip-diff\fP option. That can be useful when there are object name differences only that you want to ignore. .IP 4. 3 Check table row counts .sp This check ensures that both tables have the same number of rows. This does not ensure that the table data is consistent. It is merely a cursory check to indicate possible missing rows in one table or the other. The data consistency check identifies the missing rows. To skip this test, use the \fI\%--skip-row-count\fP option. .IP 5. 3 Check table data consistency .sp This check identifies both changed rows as well as missing rows from one or another of the tables in the databases. Changed rows are displayed as a diff\-style report with the format chosen (\fBGRID\fP by default) and missing rows are also displayed using the format chosen. To skip this test, use the \fI\%--skip-data-check\fP option. .UNINDENT .sp You may want to use the \fB\-\-skip\-xxx\fP options to run only one of the tests. This might be helpful when working to bring two databases into synchronization, to avoid running all of the tests repeatedly during the process. .sp Each test completes with one of the following states: .INDENT 0.0 .TP .B \fBpass\fP The test succeeded. .TP .B \fBFAIL\fP The test failed. Errors are displayed following the test state line. .TP .B \fBSKIP\fP The test was skipped due to a missing prerequisite or a skip option. .TP .B \fBWARN\fP The test encountered an unusual but not fatal error. .TP .B \fB\-\fP The test is not applicable to this object. .UNINDENT .sp To specify how to display diff\-style output, use one of the following values with the \fI\-\-difftype\fP option: .INDENT 0.0 .TP .B \fBunified\fP (default) Display unified format output. .TP .B \fBcontext\fP Display context format output. .TP .B \fBdiffer\fP Display differ\-style format output. .TP .B \fBsql\fP Display SQL transformation statement output. .UNINDENT .sp To specify how to display output for changed or missing rows, use one of the following values with the \fI\-\-format\fP option: .INDENT 0.0 .TP .B \fBgrid\fP (default) Display output in grid or table format like that of the \fBmysql\fP monitor. .TP .B \fBcsv\fP Display output in comma\-separated values format. .TP .B \fBtab\fP Display output in tab\-separated format. .TP .B \fBvertical\fP Display output in single\-column format like that of the \fB\eG\fP command for the \fBmysql\fP monitor. .UNINDENT .sp The \fI\-\-changes\-for\fP option controls the direction of the difference (by specifying the object to be transformed) in either the difference report (default) or the transformation report (designated with the \fI\-\-difftype=sql\fP option). Consider the following command: .sp .nf .ft C mysqldbcompare \-\-server1=root@host1 \-\-server2=root@host2 \-\-difftype=sql \e db1:dbx .ft P .fi .sp The leftmost database (\fBdb1\fP) exists on the server designated by the \fI\-\-server1\fP option (\fBhost1\fP). The rightmost database (\fBdbx\fP) exists on the server designated by the \fI\-\-server2\fP option (\fBhost2\fP). .INDENT 0.0 .IP \(bu 2 \fI\-\-changes\-for=server1\fP: Produce output that shows how to make the definitions of objects on \fBserver1\fP like the definitions of the corresponding objects on \fBserver2\fP. .IP \(bu 2 \fI\-\-changes\-for=server2\fP: Produce output that shows how to make the definitions of objects on \fBserver2\fP like the definitions of the corresponding objects on \fBserver1\fP. .UNINDENT .sp The default direction is \fBserver1\fP. .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 If the utility is to be run on a server that has binary logging enabled, and you do not want the comparison steps logged, use the \fI\%--disable-binary-logging\fP option. .SH OPTIONS .sp \fBmysqldbcompare\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 \-\-changes\-for= Specify the server to show transformations to match the other server. For example, to see the transformation for transforming object definitions on server1 to match the corresponding definitions on server2, use \fI\-\-changes\-for=server1\fP. Permitted values are \fBserver1\fP and \fBserver2\fP. The default is \fBserver1\fP. .UNINDENT .INDENT 0.0 .TP .B \-\-difftype=, \-d Specify the difference display format. Permitted format values are \fBunified\fP, \fBcontext\fP, \fBdiffer\fP, and \fBsql\fP. The default is \fBunified\fP. .UNINDENT .INDENT 0.0 .TP .B \-\-disable\-binary\-logging If binary logging is enabled, disable it during the operation to prevent comparison operations from being written to the binary log. Note: Disabling binary logging requires the \fBSUPER\fP privilege. .UNINDENT .INDENT 0.0 .TP .B \-\-format=, \-f Specify the display format for changed or missing rows. Permitted format values are \fBgrid\fP, \fBcsv\fP, \fBtab\fP, and \fBvertical\fP. The default is \fBgrid\fP. .UNINDENT .INDENT 0.0 .TP .B \-\-quiet, \-q Do not print anything. Return only an exit code of success or failure. .UNINDENT .INDENT 0.0 .TP .B \-\-run\-all\-tests, \-a Do not halt at the first difference found. Process all objects. .UNINDENT .INDENT 0.0 .TP .B \-\-server1= Connection information for the first server in <\fIuser\fP>[:<\fIpasswd\fP>]@<\fIhost\fP>[:<\fIport\fP>][:<\fIsocket\fP>] format. .UNINDENT .INDENT 0.0 .TP .B \-\-server2= Connection information for the second server in <\fIuser\fP>[:<\fIpasswd\fP>]@<\fIhost\fP>[:<\fIport\fP>][:<\fIsocket\fP>] format. .UNINDENT .INDENT 0.0 .TP .B \-\-show\-reverse Produce a transformation report containing the SQL statements to conform the object definitions specified in reverse. For example, if \-\-changes\-for is set to server1, also generate the transformation for server2. Note: The reverse changes are annotated and marked as comments. .UNINDENT .INDENT 0.0 .TP .B \-\-skip\-data\-check Skip the data consistency check. .UNINDENT .INDENT 0.0 .TP .B \-\-skip\-diff Skip the object definition difference check. .UNINDENT .INDENT 0.0 .TP .B \-\-skip\-object\-compare Skip the object comparison check. .UNINDENT .INDENT 0.0 .TP .B \-\-skip\-row\-count Skip the row count check. .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 .INDENT 0.0 .TP .B \-\-width= Change the display width of the test report. The default is 75 characters. .UNINDENT .SH NOTES .sp The login user must have the appropriate permissions to read all databases and tables listed. .sp For the \fI\-\-difftype\fP option, the permitted values are not case sensitive. In addition, values may be specified as any unambiguous prefix of a valid value. For example, \fI\-\-difftype=d\fP specifies the differ type. An error occurs if a prefix matches more than one valid value. .SH EXAMPLES .sp Use the following command to compare the \fBemp1\fP and \fBemp2\fP databases on the local server, and run all tests even if earlier tests fail: .sp .nf .ft C $ mysqldbcompare \-\-server1=root@localhost emp1:emp2 \-\-run\-all\-tests # server1 on localhost: ... connected. # Checking databases emp1 on server1 and emp2 on server2 WARNING: Objects in server2:emp2 but not in server1:emp1: TRIGGER: trg PROCEDURE: p1 TABLE: t1 VIEW: v1 Defn Row Data Type Object Name Diff Count Check \-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\- FUNCTION f1 pass \- \- TABLE departments pass pass FAIL Data differences found among rows: \-\-\- emp1.departments +++ emp2.departments @@ \-1,4 +1,4 @@ ************************* 1. row ************************* dept_no: d002 \- dept_name: dunno + dept_name: Finance 1 rows. Rows in emp1.departments not in emp2.departments ************************* 1. row ************************* dept_no: d008 dept_name: Research 1 rows. Rows in emp2.departments not in emp1.departments ************************* 1. row ************************* dept_no: d100 dept_name: stupid 1 rows. TABLE dept_manager pass pass pass Database consistency check failed. # ...done .ft P .fi .sp Given: two databases with the same table layout. Data for each table contains: .sp .nf .ft C mysql> select * from db1.t1; +\-\-\-+\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-+ | a | b | +\-\-\-+\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-+ | 1 | Test 789 | | 2 | Test 456 | | 3 | Test 123 | | 4 | New row \- db1 | +\-\-\-+\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-+ 4 rows in set (0.00 sec) mysql> select * from db2.t1; +\-\-\-+\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-+ | a | b | +\-\-\-+\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-+ | 1 | Test 123 | | 2 | Test 456 | | 3 | Test 789 | | 5 | New row \- db2 | +\-\-\-+\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-+ 4 rows in set (0.00 sec) .ft P .fi .sp To generate the SQL statements for data transformations to make \fBdb1.t1\fP the same as \fBdb2.t1\fP, use the \fI\-\-changes\-for=server1\fP option. We must also include the \fI\-a\fP option to ensure that the data consistency test is run. The following command illustrates the options used and an excerpt from the results generated: .sp .nf .ft C $ mysqldbcompare \-\-server1=root:root@localhost \e \-\-server2=root:root@localhost db1:db2 \-\-changes\-for=server1 \-a \e \-\-difftype=sql [...] # Defn Row Data # Type Object Name Diff Count Check # \-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\- # TABLE t1 pass pass FAIL # # Data transformations for direction = server1: # Data differences found among rows: UPDATE db1.t1 SET b = \(aqTest 123\(aq WHERE a = \(aq1\(aq; UPDATE db1.t1 SET b = \(aqTest 789\(aq WHERE a = \(aq3\(aq; DELETE FROM db1.t1 WHERE a = \(aq4\(aq; INSERT INTO db1.t1 (a, b) VALUES(\(aq5\(aq, \(aqNew row \- db2\(aq); # Database consistency check failed. # # ...done .ft P .fi .sp Similarly, when the same command is run with \fI\-\-changes\-for=server2\fP and \fI\-\-difftype=sql\fP, the following report is generated: .sp .nf .ft C $ mysqldbcompare \-\-server1=root:root@localhost \e \-\-server2=root:root@localhost db1:db2 \-\-changes\-for=server2 \-a \e \-\-difftype=sql [...] # Defn Row Data # Type Object Name Diff Count Check # \-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\- # TABLE t1 pass pass FAIL # # Data transformations for direction = server2: # Data differences found among rows: UPDATE db2.t1 SET b = \(aqTest 789\(aq WHERE a = \(aq1\(aq; UPDATE db2.t1 SET b = \(aqTest 123\(aq WHERE a = \(aq3\(aq; DELETE FROM db2.t1 WHERE a = \(aq5\(aq; INSERT INTO db2.t1 (a, b) VALUES(\(aq4\(aq, \(aqNew row \- db1\(aq); .ft P .fi .sp With the \fI\-\-difftype=sql\fP SQL generation option set, \fI\-\-show\-reverse\fP shows the object transformations in both directions. Here is an excerpt of the results: .sp .nf .ft C $ mysqldbcompare \-\-server1=root:root@localhost \e \-\-server2=root:root@localhost db1:db2 \-\-changes\-for=server1 \e \-\-show\-reverse \-a \-\-difftype=sql [...] # Defn Row Data # Type Object Name Diff Count Check # \-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\-\- # TABLE t1 pass pass FAIL # # Data transformations for direction = server1: # Data differences found among rows: UPDATE db1.t1 SET b = \(aqTest 123\(aq WHERE a = \(aq1\(aq; UPDATE db1.t1 SET b = \(aqTest 789\(aq WHERE a = \(aq3\(aq; DELETE FROM db1.t1 WHERE a = \(aq4\(aq; INSERT INTO db1.t1 (a, b) VALUES(\(aq5\(aq, \(aqNew row \- db2\(aq); # Data transformations for direction = server2: # Data differences found among rows: UPDATE db2.t1 SET b = \(aqTest 789\(aq WHERE a = \(aq1\(aq; UPDATE db2.t1 SET b = \(aqTest 123\(aq WHERE a = \(aq3\(aq; DELETE FROM db2.t1 WHERE a = \(aq5\(aq; INSERT INTO db2.t1 (a, b) VALUES(\(aq4\(aq, \(aqNew row \- db1\(aq); # Database consistency check failed. # # ...done .ft P .fi .SH COPYRIGHT .sp Copyright (c) 2011, 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., 59 Temple Place, Suite 330, Boston, MA 02111\-1307 USA .SH AUTHOR MySQL Utilities Team .SH COPYRIGHT 2010, Oracle and/or its affiliates. All rights reserved. .\" Generated by docutils manpage writer. .\" .