In this mode, you set up Dolt to replicate a primary MySQL. Set up can take as as little as three commands. After set up, Dolt replicates every write to your primary to Dolt and creates a Dolt commit, giving you time travel, lineage, rollback, and other database version control features on your Dolt replica.
This document will walk you through step-by-step on how to get Dolt running as a MySQL replica on your host. It will show off some unique version control features you get in this set up, including finding and fixing a bad change on primary.
Start a Local MySQL Server
First, we need a running MySQL instance. We'll consider this our "primary" database.
I use homebrew on my Mac. To get MySQL and start it, I open a terminal and run:
$brewinstallmysql$brewservicesstartmysql
This starts a MySQL on port 3306. I can connect to it with:
$mysql-urootWelcometotheMySQLmonitor.Commandsendwith ; or \g.YourMySQLconnectionidis14Serverversion:8.0.32HomebrewCopyright (c) 2000, 2023, Oracle and/or its affiliates.OracleisaregisteredtrademarkofOracleCorporationand/oritsaffiliates.Othernamesmaybetrademarksoftheirrespectiveowners.Type'help;'or'\h'forhelp.Type'\c'toclearthecurrentinputstatement.mysql>
Simple enough. Keep that open. You're going to need it.
Prepare Your Primary MySQL for a Replica
Now, you have to prepare MySQL to have a replica. This requires the following configuration which are on by default. So, don't touch these if you're starting fresh like me.
BINLOG_FORMAT must be set to ROW, which is the default in MySQL 8.0.
LOG_BIN must be set to ON, which is the default in MySQL 8.0.
SERVER_ID must be set to any positive integer (so long as there is not a replica server using that same ID). The default here is 1.
Now, for the things you have to change. First you need to turn on ENFORCE_GTID_CONSISTENCY. Go to the you mysql client we started in step one and run the following query.
Finally, you have to change GTID_MODE to ON. It is OFF by default and you can't go directly from OFF to ON. So, step through the options up to ON like so.
To make sure you have everything set up right, run the following and make sure the table looks the same.
mysql> SHOW VARIABLES WHERE Variable_Name LIKE '%gtid_mode' OR Variable_Name LIKE '%enforce_gtid_consistency' OR Variable_Name LIKE '%binlog_format' OR Variable_Name LIKE 'server_id';
+--------------------------+-------+
| Variable_name | Value |
+--------------------------+-------+
| binlog_format | ROW |
| enforce_gtid_consistency | ON |
| gtid_mode | ON |
| server_id | 1 |
+--------------------------+-------+
Dolt needs a place to put your databases. I put mine in ~/dolt_replica.
$cd~$mkdirdolt_replica$cddolt_replica
Start a dolt sql-server. This is a MySQL compatible database server similar to the one you started in the first section. You need to run it on a different port than 3306 because your MySQL is running there. So, we'll start it on port 1234 using the -P option. I'm also going to start the server with --loglevel at debug so I can show you the queries replication is running.
The shell will just hang there. That means Dolt is running. Any errors you encounter running Dolt will be printed here. Because we're in debug mode, you can also see the queries run against the server in this log.
Configure Dolt as a Replica
Open a new terminal and connect a MySQL client to your running Dolt just like you did to MySQL above, but this time specify port 1243 and host 127.0.0.1 to force MySQL through the TCP interface. Without the host specified it will connect using the socket interface to your running MySQL, not Dolt like you want.
$mysql-h127.0.0.1-P1234-urootWelcometotheMySQLmonitor.Commandsendwith ; or \g.YourMySQLconnectionidis1Serverversion:5.7.9-VitessCopyright (c) 2000, 2023, Oracle and/or its affiliates.OracleisaregisteredtrademarkofOracleCorporationand/oritsaffiliates.Othernamesmaybetrademarksoftheirrespectiveowners.Type'help;'or'\h'forhelp.Type'\c'toclearthecurrentinputstatement.mysql>
Now you need to run three commands. First, make sure the replica server has a unique server_id not used by any source or other replicas in our system. We'll use `2'.
You now have a Dolt replica of a running MySQL! If you have any data in the binlog of the MySQL (ie. you didn't start from scratch), that data will replicate over to Dolt right now.
Write Something on the Primary
Now it's time to test out what you created. We'll start by creating a databases and a table.
On the primary, run the following queries.
mysql>createdatabase foo;Query OK, 1row affected (0.00 sec)mysql>use foo;Database changedmysql>createtable t (c1 intprimary key, c2 int);Query OK, 0rows affected (0.01 sec)mysql> show tables;+---------------+| Tables_in_foo |+---------------+| t |+---------------+1rowinset (0.01 sec)mysql>insert into t values (0,0);Query OK, 1row affected (0.01 sec)
You can see the queries replicating in the Dolt log:
Let's hop over to the mysql client connected to Dolt and inspect it just to make sure.
mysql>use foo;Reading table information for completion of tableand column namesYou can turn off this feature toget a quicker startup with-ADatabase changedmysql> show tables;+---------------+| Tables_in_foo |+---------------+| t |+---------------+1rowinset (0.01 sec)mysql>select*from t;+------+------+| c1 | c2 |+------+------+| 0 | 0 |+------+------+1rowinset (0.01 sec)
The new database foo and the table t along with it's single row have replicated.
Inspect the Commit Log
Now to show off the first new feature, the Dolt Commit log. The Dolt replica makes a Dolt commit after every transaction sent from the primary so you can see what changed and when.
Dolt has a number of system tables, functions, and procedures to expose the version control features. These tables, functions, and procedures are inspired by their Git equivalents, so git log becomes the dolt_log system table.
It looks like c1 and c2 both went from NULL to 0 in that commit, just as we'd expect. With a Dolt replica, you get a queryable audit log of every cell in your database.
It takes a bit longer than 25 seconds for Dolt to replicate that all over, especially with the log level at debug, but it should be done in under a minute.
Over on my Dolt replica, I can see the employees database and its tables.
mysql> show databases;+--------------------+| Database |+--------------------+| employees || foo || information_schema || mysql |+--------------------+4rowsinset (0.00 sec)mysql>use employees;Reading table information for completion of tableand column namesYou can turn off this feature toget a quicker startup with-ADatabase changedmysql> show tables;+----------------------+| Tables_in_employees |+----------------------+| current_dept_emp || departments || dept_emp || dept_emp_latest_date || dept_manager || employees || salaries || titles |+----------------------+8rowsinset (0.00 sec)
Make a bad change
Now, let's do something crazy. We're going to mix a bad change in with a couple good changes and use the Dolt replica to find and revert the change.
Let's say in this case, people are reporting their historical salaries have changed. We have a clue that something is wrong in the database. Let's head over to the Dolt replica and see what's up.
First, we want to find the changes in the last 10 transactions that touched the salaries table. To do this we use the unscoped dolt_diff table to see what tables changes in each commit.
It looks like the bottom seven are the import because they are happening back to back. Let's look at the diff between the third and first commit, 4te2i1qheceek434m3uoqsuejfv6f0nu and 649fgvojpthn1e21bqrdlv3r3bht4rqb.
We're getting closer. We have a couple good changes in there, the last two, but we see the badly modified rows pretty clearly. Let's compare the last two commits.
Take a minute to marvel at what we just did. We were able to identify what changed from a update salaries set salary=salary-1 order by rand() limit 5; query all using queryable system tables on a replica. What a time to be alive! Now let's revert the change.
Revert a bad change
If you were running Dolt as the primary database, reverting a bad change is as simple as calling dolt_revert(). But since we're running Dolt as a replica, we need Dolt to produce a SQL patch to revert the bad changes. To do this, we're going to make a branch on the replica, revert the change, and then use the dolt_patch() function to get the SQL we need to apply to our primary database.
First, we use call dolt_checkout() to create a branch. Our revert changes will now be isolated from the replicating branch, main.
mysql>call dolt_checkout('-b', 'revert_bad_change');+--------+| status |+--------+| 0 |+--------+1rowinset (0.02 sec)
mysql>selectreplace(group_concat(statement), ',', '') from dolt_patch('HEAD^', 'HEAD');+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| replace(group_concat(statement), ',', '') |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| UPDATE `salaries` SET `salary`=76541 WHERE `emp_no`=203464 AND `from_date`='1997-02-20';UPDATE `salaries` SET `salary`=48855 WHERE `emp_no`=255639 AND `from_date`='1994-12-12';UPDATE `salaries` SET `salary`=56425 WHERE `emp_no`=291810 AND `from_date`='1997-09-15';UPDATE `salaries` SET `salary`=47130 WHERE `emp_no`=416268 AND `from_date`='1996-02-03';UPDATE `salaries` SET `salary`=67239 WHERE `emp_no`=441152 AND `from_date`='1992-09-09'; |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
1rowinset (0.00 sec)
We now have the SQL we need to run on the primary. Let's run it and make sure there is no diff between main and the revert_bad_change branch we're working on after it replicates. This is now in my primary mysql shell.
mysql> UPDATE `salaries` SET `salary`=76541 WHERE `emp_no`=203464 AND `from_date`='1997-02-20';UPDATE `salaries` SET `salary`=48855 WHERE `emp_no`=255639 AND `from_date`='1994-12-12';UPDATE `salaries` SET `salary`=56425 WHERE `emp_no`=291810 AND `from_date`='1997-09-15';UPDATE `salaries` SET `salary`=47130 WHERE `emp_no`=416268 AND `from_date`='1996-02-03';UPDATE `salaries` SET `salary`=67239 WHERE `emp_no`=441152 AND `from_date`='1992-09-09';
Query OK, 0rows affected (0.00 sec)Rowsmatched: 1 Changed: 0 Warnings: 0Query OK, 1row affected (0.01 sec)Rowsmatched: 1 Changed: 1 Warnings: 0Query OK, 1row affected (0.00 sec)Rowsmatched: 1 Changed: 1 Warnings: 0Query OK, 1row affected (0.01 sec)Rowsmatched: 1 Changed: 1 Warnings: 0Query OK, 1row affected (0.00 sec)Rowsmatched: 1 Changed: 1 Warnings: 0
And back over on Dolt we should now see no difference between main and our branch revert_bad_change.
Phew, that was pretty awesome. I was able to find a bad change using my Dolt replica, generate a patch to revert it on my primary, apply the patch, and make sure everything was right with the world again. With a Dolt replica, you never have to worry about bad administrator queries again!