5.7.1 mysqldiff — Identify Differences Among Database Objects

This utility reads the definitions of objects and compares them using a diff-like method to determine whether they are the same. The utility displays the differences for objects that are not the same.

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.

The comparison may be run against two databases of different names on a single server by specifying only the --server1 option. The user can also connect to another server by specifying the --server2 option. In this case, db1 is taken from server1 and db2 from server2.

When a database pair is specified, all objects in one database are compared to the corresponding objects in the other. Any objects not appearing in either database produce an error.

To compare a specific pair of objects, add an object name to each database name in db.obj format. For example, use db1.obj1:db2.obj2 to compare two named objects, or db1.obj1 to compare an object with the same name in databases with the same name. It is not legal to mix a database name with an object name. For example, db1.obj1:db2 and db1:db2.obj2 are illegal.

The comparison may be run against a single server for comparing two databases of different names on the same server by specifying only the --server1 option. Alternatively, you can also connect to another server by specifying the --server2 option. In this case, the first object to compare is taken from server1 and the second from server2.

By default, the utility generates object differences as a difference report. However, you can generate a transformation report containing SQL statements for transforming the objects for conformity instead. Use the 'sql' value for the --difftype option to produce a listing that contains the appropriate ALTER commands to conform the object definitions for the object pairs specified. If a transformation cannot be formed, the utility reports the diff of the object along with a warning statement. See important limitations in the NOTES section.

To specify how to display diff-style output, use one of the following values with the --difftype option:

The --changes-for 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 --difftype=sql option). Consider the following command:

mysqldiff --server1=root@host1 --server2=root@host2 --difftype=sql \
  db1.table1:dbx.table3

The leftmost database (db1) exists on the server designated by the --server1 option (host1). The rightmost database (dbx) exists on the server designated by the --server2 option (host2).

The default direction is server1.

For sql difference format, you can also see the reverse transformation by specifying the --show-reverse option.

The utility stops on the first occurrence of missing objects or when an object does not match. To override this behavior, specify the --force option to cause the utility to attempt to compare all objects listed as arguments.

OPTIONS

mysqldiff accepts the following command-line options:

NOTES

You must provide connection parameters (user, host, password, and so forth) for an account that has the appropriate privileges to access all objects to be compared.

The SQL transformation feature has these known limitations:

For the --difftype option, the permitted values are not case sensitive. In addition, values may be specified as any unambiguous prefix of a valid value. For example, --difftype=d specifies the differ type. An error occurs if a prefix matches more than one valid value.

The path to the MySQL client tools should be included in the PATH environment variable in order to use the authentication mechanism with login-paths. This will allow the utility to use the my_print_defaults tools which is required to read the login-path values from the login configuration file (.mylogin.cnf).

If any database object identifier specified as an argument contains special characters or is a reserved word, then it must be appropriately quoted with backticks (`). In turn, names quoted with backticks must also be quoted with single or double quotes depending on the operating system, i.e. (") in Windows or (') in non-Windows systems, in order for the utilities to read backtick quoted identifiers as a single argument. For example, to show the difference between table weird`table1 from database weird`db.name and table weird`table2 from database other:weird`db.name, the objects pair must be specified using the following syntax (in non-Windows): '`weird``db.name`.`weird``table1`:`other:weird``db.name`.`weird``table2`'.

EXAMPLES

To compare the employees and emp databases on the local server, use this command:

$ mysqldiff --server1=root@localhost employees:emp1
# server1 on localhost: ... connected.
WARNING: Objects in server1:employees but not in server2:emp1:
  EVENT: e1
Compare failed. One or more differences found.

$ mysqldiff --server1=root@localhost \
           employees.t1:emp1.t1 employees.t3:emp1.t3
# server1 on localhost: ... connected.
# Comparing employees.t1 to emp1.t1                                [PASS]
# server1 on localhost: ... connected.
# Comparing employees.t3 to emp1.t3                                [PASS]
Success. All objects are the same.

$ mysqldiff --server1=root@localhost \
         employees.salaries:emp1.salaries --differ
# server1 on localhost: ... connected.
# Comparing employees.salaries to emp1.salaries                    [FAIL]
# Object definitions are not the same:
  CREATE TABLE `salaries` (
    `emp_no` int(11) NOT NULL,
    `salary` int(11) NOT NULL,
    `from_date` date NOT NULL,
    `to_date` date NOT NULL,
    PRIMARY KEY (`emp_no`,`from_date`),
    KEY `emp_no` (`emp_no`)
- ) ENGINE=InnoDB DEFAULT CHARSET=latin1
?           ^^^^^
+ ) ENGINE=MyISAM DEFAULT CHARSET=latin1
?          ++ ^^^
Compare failed. One or more differences found.

The following examples show how to generate a transformation report. Assume the following object definitions:

Host1:

CREATE TABLE db1.table1 (num int, misc char(30));

Host2:

CREATE TABLE dbx.table3 (num int, notes char(30), misc char(55));

To generate a set of SQL statements that transform the definition of db1.table1 to dbx.table3, use this command:

$ mysqldiff --server1=root@host1 --server2=root@host2 \
      --changes-for=server1 --difftype=sql \
      db1.table1:dbx.table3
# server1 on host1: ... connected.
# server2 on host2: ... connected.
# Comparing db1.table1 to dbx.table3                               [FAIL]
# Transformation statements:

ALTER TABLE db1.table1
  ADD COLUMN notes char(30) AFTER a,
  CHANGE COLUMN misc misc char(55);

Compare failed. One or more differences found.

To generate a set of SQL statements that transform the definition of dbx.table3 to db1.table1, use this command:

$ mysqldiff --server1=root@host1 --server2=root@host2 \
      --changes-for=server2 --difftype=sql \
      db1.table1:dbx.table3
# server1 on host1: ... connected.
# server2 on host2: ... connected.
# Comparing db1.table1 to dbx.table3                               [FAIL]
# Transformation statements:

ALTER TABLE dbx.table3
  DROP COLUMN notes,
  CHANGE COLUMN misc misc char(30);

Compare failed. One or more differences found.

To generate a set of SQL statements that transform the definitions of dbx.table3 and db1.table1 in both directions, use this command:

$ mysqldiff --server1=root@host1 --server2=root@host2 \
      --show-reverse --difftype=sql \
      db1.table1:dbx.table3
# server1 on host1: ... connected.
# server2 on host2: ... connected.
# Comparing db1.table1 to dbx.table3                               [FAIL]
# Transformation statements:

# --destination=server1:
ALTER TABLE db1.table1
  ADD COLUMN notes char(30) AFTER a,
  CHANGE COLUMN misc misc char(55);

# --destination=server2:
# ALTER TABLE dbx.table3
#   DROP COLUMN notes,
#   CHANGE COLUMN misc misc char(30);

Compare failed. One or more differences found.

PERMISSIONS REQUIRED

The user must have SELECT privileges for both objects on both servers as well as SELECT on the mysql database.