├── .gitignore ├── tests ├── helpers │ ├── client.js │ ├── server.js │ ├── client_object.js │ ├── server_object.js │ ├── server_data.js │ └── client_data.js └── sync.js ├── schema ├── server │ ├── database.sql │ ├── schema.sql │ └── sync.sql └── client │ ├── schema.sql │ └── sync.sql ├── package.json ├── lib ├── server_help.js ├── client_sync.js └── server_sync.js ├── Makefile └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | node_modules/ 2 | tmp/ 3 | 4 | -------------------------------------------------------------------------------- /tests/helpers/client.js: -------------------------------------------------------------------------------- 1 | var sqlite3 = require('sqlite3').verbose(); 2 | 3 | exports.make = function(file) { 4 | return new sqlite3.Database(file); 5 | }; 6 | -------------------------------------------------------------------------------- /schema/server/database.sql: -------------------------------------------------------------------------------- 1 | DROP DATABASE IF EXISTS sync; 2 | CREATE DATABASE sync CHARACTER SET utf8 COLLATE utf8_general_ci; 3 | USE sync; 4 | SET storage_engine = InnoDB; 5 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "sql-sync", 3 | "version": "0.0.1", 4 | "dependencies": { 5 | "sqlite3": "x", 6 | "node-uuid": "x", 7 | "async": "x", 8 | "mysql": "2.0.0-alpha8", 9 | "mocha": "x" 10 | } 11 | } 12 | -------------------------------------------------------------------------------- /tests/helpers/server.js: -------------------------------------------------------------------------------- 1 | var mysql = require('mysql'); 2 | 3 | // Creates MySQL connection to the server. 4 | 5 | var connection = exports.connection = mysql.createConnection({ 6 | host: 'mysql', 7 | user: 'test', 8 | password: 'test' 9 | }); 10 | 11 | connection.connect(); 12 | connection.query('USE sync'); 13 | -------------------------------------------------------------------------------- /lib/server_help.js: -------------------------------------------------------------------------------- 1 | // Helper function to debug 2 | // queries. 3 | 4 | exports.query = function(con, sql, params, cb) { 5 | if (typeof params === 'function') { 6 | cb = params; 7 | params = []; 8 | } 9 | con.query(sql, params, function(err, results) { 10 | cb(err, results); 11 | }); 12 | }; -------------------------------------------------------------------------------- /schema/server/schema.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE note( 2 | uuid CHAR(36) NOT NULL, 3 | title VARCHAR(255) NOT NULL, 4 | content TEXT DEFAULT NULL, 5 | PRIMARY KEY (uuid) 6 | ); 7 | 8 | -- 1:n relationship with note 9 | 10 | CREATE TABLE comment ( 11 | uuid CHAR(36) NOT NULL, 12 | note_uuid CHAR(36) NOT NULL, 13 | title VARCHAR(255) NOT NULL, 14 | content TEXT DEFAULT NULL, 15 | PRIMARY KEY(uuid) 16 | ); -------------------------------------------------------------------------------- /schema/client/schema.sql: -------------------------------------------------------------------------------- 1 | BEGIN TRANSACTION; 2 | 3 | CREATE TABLE note ( 4 | uuid VARCHAR(255) NOT NULL, 5 | title VARCHAR(255) NOT NULL, 6 | content TEXT DEFAULT NULL, 7 | PRIMARY KEY(uuid) 8 | ); 9 | 10 | -- 1:n relationship with note 11 | 12 | CREATE TABLE comment ( 13 | uuid VARCHAR(255) NOT NULL, 14 | note_uuid VARCHAR(255) NOT NULL, 15 | title VARCHAR(255) NOT NULL, 16 | content TEXT DEFAUL NULL, 17 | PRIMARY KEY(uuid) 18 | ); 19 | 20 | COMMIT TRANSACTION; -------------------------------------------------------------------------------- /tests/helpers/client_object.js: -------------------------------------------------------------------------------- 1 | var async = require('async'); 2 | 3 | // Helper module to convert the 4 | // client data into a single JS object. 5 | // Used for testing. 6 | 7 | // Retrieves all notes. 8 | 9 | function allNotes(db, cb) { 10 | var sql = 'SELECT * FROM note ORDER BY uuid'; 11 | db.all(sql, cb); 12 | } 13 | 14 | // Retrieves all comments. 15 | 16 | function allComments(db, cb) { 17 | var sql = 'SELECT * FROM comment ORDER BY uuid'; 18 | db.all(sql, cb); 19 | } 20 | 21 | // Converts all client data into large js object. 22 | 23 | module.exports = function(db, cb) { 24 | async.waterfall([ 25 | function(cb) { 26 | async.series([ 27 | async.apply(allNotes, db), 28 | async.apply(allComments, db) 29 | ], cb); 30 | }, 31 | function(data, cb) { 32 | cb(null, { notes: data[0], comments: data[1] }); 33 | } 34 | ], cb); 35 | }; 36 | -------------------------------------------------------------------------------- /tests/helpers/server_object.js: -------------------------------------------------------------------------------- 1 | var async = require('async'); 2 | var query = require('../../lib/server_help').query; 3 | 4 | // Helper module to convert all 5 | // server data into a JS object. 6 | 7 | // Retrieves all notes. 8 | 9 | function allNotes(con, cb) { 10 | var sql = 'SELECT * FROM note ORDER BY uuid'; 11 | query(con, sql, cb); 12 | } 13 | 14 | // Retrieves all comments. 15 | 16 | function allComments(con, cb) { 17 | var sql = 'SELECT * FROM comment ORDER BY uuid'; 18 | query(con, sql, cb); 19 | } 20 | 21 | // Converts all server data into a large js object. 22 | 23 | module.exports = function(con, cb) { 24 | async.waterfall([ 25 | function(cb) { 26 | async.series([ 27 | async.apply(allNotes, con), 28 | async.apply(allComments, con) 29 | ], cb); 30 | }, 31 | function(results, cb) { 32 | cb(null, { notes: results[0], comments: results[1] }); 33 | } 34 | ], cb); 35 | }; -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | JS = $(wildcard *.js) $(wildcard lib/*.js) $(wildcard tests/*.js) $(wildcard tests/helpers/*.js) 2 | 3 | client: tmp/test.sqlite tmp/c1.sqlite tmp/c2.sqlite 4 | 5 | tmp/%.sqlite: tmp/client.sql 6 | cat $< | sqlite3 $@ 7 | 8 | tmp/client.sql: schema/client/schema.sql schema/client/sync.sql 9 | cat $+ > $@ 10 | 11 | tmp/server.sql: schema/server/database.sql schema/server/schema.sql schema/server/sync.sql 12 | cat $+ > $@ 13 | 14 | server: tmp/server.sql 15 | cat $< | mysql \ 16 | --show-warnings \ 17 | --default-character-set=utf8 \ 18 | --batch \ 19 | --disable-auto-rehash \ 20 | --user=test \ 21 | --password=test \ 22 | --host=mysql 23 | 24 | test-sync: 25 | mocha tests/sync.js 26 | 27 | test: check clean client server test-sync 28 | 29 | check: $(JS) 30 | jshint $+ 31 | 32 | clean: 33 | rm -f tmp/* 34 | rm -rf docs/* 35 | 36 | docs: 37 | docco -o docs -l parallel $(JS) 38 | 39 | upload-docs: docs 40 | ssh www-data@infdot.com mkdir -p /var/www/doc/sql-sync 41 | scp docs/* www-data@infdot.com:/var/www/doc/sql-sync 42 | 43 | .PHONY: clean sqlite server test test-server test-client test-sync check docs upload-docs 44 | -------------------------------------------------------------------------------- /schema/server/sync.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE sync ( 2 | action TINYINT UNSIGNED NOT NULL, -- 0 - insert/modify, 1 - delete 3 | keyval CHAR(36) NOT NULL, -- table row key value 4 | tid TINYINT UNSIGNED NOT NULL, -- table identifier 5 | rev BIGINT UNSIGNED NOT NULL, 6 | PRIMARY KEY (keyval) 7 | ); 8 | 9 | -- Metainfo about synced tables. 10 | 11 | CREATE TABLE sync_table ( 12 | tid TINYINT UNSIGNED NOT NULL, 13 | name VARCHAR(255) NOT NULL, 14 | keycol VARCHAR(255) NOT NULL, 15 | PRIMARY KEY (tid), 16 | UNIQUE (name) 17 | ); 18 | 19 | INSERT INTO sync_table (tid, name, keycol) VALUES 20 | (0, 'note', 'uuid'), (1, 'comment', 'uuid'); 21 | 22 | CREATE TABLE revision ( 23 | rev BIGINT UNSIGNED NOT NULL 24 | ); 25 | 26 | INSERT INTO revision (rev) VALUES (0); 27 | 28 | delimiter | 29 | CREATE PROCEDURE sync_mark ( 30 | in_keyval CHAR(36), 31 | in_tid TINYINT UNSIGNED, 32 | in_action VARCHAR(10) 33 | ) 34 | BEGIN 35 | INSERT INTO sync (action, keyval, tid, rev) 36 | VALUES ( 37 | in_action, 38 | in_keyval, 39 | in_tid, 40 | (SELECT rev + 1 FROM revision) 41 | ) ON DUPLICATE KEY UPDATE action = VALUES(action), rev = VALUES(rev); 42 | UPDATE revision SET rev = rev + 1; 43 | END 44 | | 45 | 46 | CREATE TRIGGER note_insert 47 | AFTER INSERT ON note FOR EACH ROW 48 | BEGIN CALL sync_mark(NEW.uuid, 0, 0); END 49 | | 50 | 51 | CREATE TRIGGER note_update 52 | AFTER UPDATE ON note FOR EACH ROW 53 | BEGIN 54 | CALL sync_mark(OLD.uuid, 0, 1); 55 | CALL sync_mark(NEW.uuid, 0, 0); 56 | END 57 | | 58 | 59 | CREATE TRIGGER note_delete 60 | AFTER DELETE ON note FOR EACH ROW 61 | BEGIN CALL sync_mark(OLD.uuid, 0, 1); END 62 | | 63 | 64 | CREATE TRIGGER comment_insert 65 | AFTER INSERT ON comment FOR EACH ROW 66 | BEGIN CALL sync_mark(NEW.uuid, 1, 0); END 67 | | 68 | 69 | CREATE TRIGGER comment_update 70 | AFTER UPDATE ON comment FOR EACH ROW 71 | BEGIN 72 | CALL sync_mark(OLD.uuid, 1, 1); 73 | CALL sync_mark(NEW.uuid, 1, 0); 74 | END 75 | | 76 | 77 | CREATE TRIGGER comment_delete 78 | AFTER DELETE ON comment FOR EACH ROW 79 | BEGIN CALL sync_mark(OLD.uuid, 1, 1); END 80 | | 81 | delimiter ; -------------------------------------------------------------------------------- /schema/client/sync.sql: -------------------------------------------------------------------------------- 1 | BEGIN TRANSACTION; 2 | 3 | -- Generic table for storing sync actions. 4 | -- Last action with on the row always takes precedence. 5 | 6 | CREATE TABLE sync ( 7 | action INTEGER NOT NULL, -- 0 - insert/modify, 1 - delete 8 | keyval CHARACTER(36) NOT NULL, -- table key 9 | tid INTEGER NOT NULL, -- table id 10 | PRIMARY KEY (keyval) ON CONFLICT REPLACE 11 | ); 12 | 13 | -- Metainfo about the synced tables. 14 | 15 | CREATE TABLE sync_table ( 16 | tid INTEGER NOT NULL, 17 | name VARCHAR(255) NOT NULL, 18 | keycol VARCHAR(255) NOT NULL, 19 | PRIMARY KEY (tid), 20 | UNIQUE (name) 21 | ); 22 | 23 | INSERT INTO sync_table (tid, name, keycol) VALUES (0, 'note', 'uuid'); 24 | INSERT INTO sync_table (tid, name, keycol) VALUES (1, 'comment', 'uuid'); 25 | 26 | -- Keeps client side revision number. 27 | -- This is not changed during data operations. 28 | -- It is only used when communicating with the server. 29 | 30 | CREATE TABLE revision ( 31 | rev UNSIGNED BIG INT NOT NULL 32 | ); 33 | 34 | INSERT INTO revision (rev) VALUES (0); 35 | 36 | -- Triggers on the note table. 37 | 38 | CREATE TRIGGER note_insert 39 | AFTER INSERT ON note FOR EACH ROW 40 | BEGIN 41 | INSERT INTO sync (action, keyval, tid) 42 | VALUES (0, NEW.uuid, 0); 43 | END; 44 | 45 | CREATE TRIGGER note_update 46 | AFTER UPDATE ON note FOR EACH ROW 47 | BEGIN 48 | INSERT INTO sync(action, keyval, tid) 49 | VALUES (1, OLD.uuid, 0); 50 | INSERT INTO sync(action, keyval, tid) 51 | VALUES (0, NEW.uuid, 0); 52 | END; 53 | 54 | CREATE TRIGGER note_delete 55 | AFTER DELETE ON note FOR EACH ROW 56 | BEGIN 57 | INSERT INTO sync(action, keyval, tid) 58 | VALUES (1, OLD.uuid, 0); 59 | END; 60 | 61 | -- Triggers on the comment table. 62 | 63 | CREATE TRIGGER comment_insert 64 | AFTER INSERT ON comment FOR EACH ROW 65 | BEGIN 66 | INSERT INTO sync (action, keyval, tid) 67 | VALUES (0, NEW.uuid, 1); 68 | END; 69 | 70 | CREATE TRIGGER comment_update 71 | AFTER UPDATE ON comment FOR EACH ROW 72 | BEGIN 73 | INSERT INTO sync(action, keyval, tid) 74 | VALUES (1, OLD.uuid, 1); 75 | INSERT INTO sync(action, keyval, tid) 76 | VALUES (0, NEW.uuid, 1); 77 | END; 78 | 79 | CREATE TRIGGER comment_delete 80 | AFTER DELETE ON comment FOR EACH ROW 81 | BEGIN 82 | INSERT INTO sync(action, keyval, tid) 83 | VALUES (1, OLD.uuid, 1); 84 | END; 85 | 86 | COMMIT TRANSACTION; -------------------------------------------------------------------------------- /tests/helpers/server_data.js: -------------------------------------------------------------------------------- 1 | var uuid = require('node-uuid'); 2 | var async = require('async'); 3 | var query = require('../../lib/server_help').query; 4 | 5 | // Helper module to generate random 6 | // data on the server side. 7 | 8 | // Inserts a random note into the server 9 | // database. 10 | 11 | var insertRandomNote = exports.insertRandomNote = function(con, cb) { 12 | var sql = 'INSERT INTO note (uuid, title, content)' + 13 | ' VALUES (?, ?, ?)'; 14 | var params = [ uuid.v4(), 'Test', 'Test test' ]; 15 | query(con, sql, params, cb); 16 | }; 17 | 18 | // Creates and inserts random comment. 19 | 20 | function insertRandomComment(con, cb) { 21 | async.waterfall([ 22 | async.apply(randomNoteUuid, con), 23 | function(uuid, cb) { 24 | insertNoteComment(con, uuid, cb); 25 | } 26 | ], cb); 27 | } 28 | 29 | // Adds random comment to the given note. 30 | 31 | function insertNoteComment(con, noteUuid, cb) { 32 | var params = [ uuid.v4(), noteUuid, 'Comment xx', 'Large text' ]; 33 | var sql = 'INSERT INTO comment (uuid, note_uuid, title, content)' + 34 | ' VALUES (?, ?, ?, ?)'; 35 | query(con, sql, params, cb); 36 | } 37 | 38 | // Finds uuid of a random note. 39 | 40 | function randomNoteUuid(con, cb) { 41 | var sql = 'SELECT uuid FROM note ORDER BY RAND() LIMIT 1'; 42 | query(con, sql, function(err, result) { 43 | cb(err, result[0].uuid); 44 | }); 45 | } 46 | 47 | // Deletes given note from the client 48 | // database. 49 | 50 | function deleteNote(con, uuid, cb) { 51 | var sql = 'DELETE FROM note WHERE uuid = ?'; 52 | query(con, sql, [ uuid ], cb); 53 | } 54 | 55 | // Deletes given note comments. 56 | 57 | function deleteNoteComments(con, uuid, cb) { 58 | var sql = 'DELETE FROM comment WHERE note_uuid = ?'; 59 | query(con, sql, [ uuid ], cb); 60 | } 61 | 62 | // Deletes random note. 63 | 64 | function deleteRandomNote(con, cb) { 65 | async.waterfall([ 66 | async.apply(randomNoteUuid, con), 67 | function(uuid, cb) { 68 | async.series([ 69 | async.apply(deleteNoteComments, con, uuid), 70 | async.apply(deleteNote, con, uuid) 71 | ], cb); 72 | } 73 | ], cb); 74 | } 75 | 76 | // Runs random operations on the server. 77 | 78 | exports.randomOps = function(con, cb) { 79 | async.series([ 80 | async.apply(insertRandomNote, con), 81 | async.apply(insertRandomNote, con), 82 | async.apply(insertRandomNote, con), 83 | async.apply(insertRandomComment, con), 84 | async.apply(insertRandomComment, con), 85 | async.apply(insertRandomComment, con), 86 | async.apply(insertRandomComment, con), 87 | async.apply(insertRandomComment, con), 88 | async.apply(insertRandomComment, con), 89 | async.apply(insertRandomComment, con), 90 | async.apply(insertRandomComment, con), 91 | async.apply(deleteRandomNote, con) 92 | ], cb); 93 | }; -------------------------------------------------------------------------------- /tests/helpers/client_data.js: -------------------------------------------------------------------------------- 1 | var uuid = require('node-uuid'); 2 | var async = require('async'); 3 | 4 | // Creates a random note. 5 | 6 | function insertRandomNote(db, cb) { 7 | var sql = 'INSERT INTO note (uuid, title, content)' + 8 | ' VALUES (?, ?, ?)'; 9 | var params = [ uuid.v4(), 'Test', 'Test test' ]; 10 | db.run(sql, params, cb); 11 | } 12 | 13 | // Creates and inserts random comment. 14 | 15 | function insertRandomComment(db, cb) { 16 | async.waterfall([ 17 | async.apply(randomNoteUuid, db), 18 | async.apply(insertNoteComment, db) 19 | ], cb); 20 | } 21 | 22 | // Adds random comment to the given note. 23 | 24 | function insertNoteComment(db, noteUuid, cb) { 25 | var params = [ uuid.v4(), noteUuid, 'Comment xx', 'Large text' ]; 26 | var sql = 'INSERT INTO comment (uuid, note_uuid, title, content)' + 27 | ' VALUES (?, ?, ?, ?)'; 28 | db.run(sql, params, cb); 29 | } 30 | 31 | // Deletes given note from the client 32 | // database. 33 | 34 | function deleteNote(db, uuid, cb) { 35 | var sql = 'DELETE FROM note WHERE uuid = ?'; 36 | db.run(sql, [ uuid ], cb); 37 | } 38 | 39 | // Deletes given note comments. 40 | // This could abso be done with foreign keys 41 | // and ON DELETE CASCADE. 42 | 43 | function deleteNoteComments(db, uuid, cb) { 44 | var sql = 'DELETE FROM comment WHERE note_uuid = ?'; 45 | db.run(sql, [ uuid ], cb); 46 | } 47 | 48 | // Deletes random note. 49 | 50 | function deleteRandomNote(db, cb) { 51 | async.waterfall([ 52 | async.apply(randomNoteUuid, db), 53 | function(uuid, cb) { 54 | async.series([ 55 | async.apply(deleteNoteComments, db, uuid), 56 | async.apply(deleteNote, db, uuid) 57 | ], cb); 58 | } 59 | ], cb); 60 | } 61 | 62 | // Finds uuid of a random note. 63 | 64 | function randomNoteUuid(db, cb) { 65 | var sql = 'SELECT uuid FROM note ORDER BY RANDOM() LIMIT 1'; 66 | db.get(sql, function(err, result) { 67 | cb(err, result.uuid); 68 | }); 69 | } 70 | 71 | // Helper to start SQLite transaction. 72 | 73 | function beginTransaction(db, cb) { 74 | db.run('BEGIN TRANSACTION', cb); 75 | } 76 | 77 | // Helper to stop SQLite transaction. 78 | 79 | function endTransaction(db, cb) { 80 | db.run('COMMIT TRANSACTION', cb); 81 | } 82 | 83 | // Runs random operations on the client. 84 | 85 | exports.randomOps = function(db, cb) { 86 | async.series([ 87 | async.apply(beginTransaction, db), 88 | async.apply(insertRandomNote, db), 89 | async.apply(insertRandomNote, db), 90 | async.apply(insertRandomNote, db), 91 | async.apply(insertRandomComment, db), 92 | async.apply(insertRandomComment, db), 93 | async.apply(insertRandomComment, db), 94 | async.apply(insertRandomComment, db), 95 | async.apply(insertRandomComment, db), 96 | async.apply(insertRandomComment, db), 97 | async.apply(insertRandomComment, db), 98 | async.apply(insertRandomComment, db), 99 | async.apply(deleteRandomNote, db), 100 | async.apply(endTransaction, db) 101 | ], cb); 102 | }; -------------------------------------------------------------------------------- /tests/sync.js: -------------------------------------------------------------------------------- 1 | var server = require('./helpers/server'); 2 | var client = require('./helpers/client'); 3 | var serverSync = require('../lib/server_sync'); 4 | var clientSync = require('../lib/client_sync'); 5 | var serverObject = require('./helpers/server_object'); 6 | var clientObject = require('./helpers/client_object'); 7 | var serverData = require('./helpers/server_data'); 8 | var clientData = require('./helpers/client_data'); 9 | var assert = require('assert'); 10 | var async = require('async'); 11 | 12 | function syncAndCheck(serverCon, clientDb, cb) { 13 | async.waterfall([ 14 | function(cb) { 15 | clientSync.findChanges(clientDb, cb); 16 | }, 17 | function(clientChanges, cb) { 18 | serverSync.sync(serverCon, clientChanges, cb); 19 | }, 20 | function(serverChanges, cb) { 21 | clientSync.applyChanges(clientDb, serverChanges, cb); 22 | }, 23 | function(cb) { 24 | serverObject(serverCon, cb); 25 | }, 26 | function(sobj, cb) { 27 | clientObject(clientDb, function(err, cobj) { 28 | cb(err, sobj, cobj); 29 | }); 30 | }, 31 | function(sobj, cobj, cb) { 32 | check(sobj, cobj); 33 | cb(); 34 | } 35 | ], function(err) { 36 | assert.ifError(err); 37 | cb(err); 38 | }); 39 | } 40 | 41 | // Checks consistency between the 42 | // two clients. 43 | 44 | function checkClients(clientDb1, clientDb2, cb) { 45 | async.series([ 46 | async.apply(clientObject, clientDb1), 47 | async.apply(clientObject, clientDb2) 48 | ], function(err, results) { 49 | assert.ifError(err); 50 | check(results[0], results[1]); 51 | cb(err); 52 | }); 53 | } 54 | 55 | function check(server, client) { 56 | //console.log('Server: %s', JSON.stringify(server.comments)); 57 | //console.log('Client: %s', JSON.stringify(client.comments)); 58 | console.log('Server notes length: %s', server.notes.length); 59 | console.log('Client notes length: %s', client.notes.length); 60 | console.log('Server comments length: %s', server.comments.length); 61 | console.log('Client comments length: %s', client.comments.length); 62 | assert.deepEqual(server, client); 63 | } 64 | 65 | describe('Sync', function() { 66 | 67 | var db1, db2; 68 | 69 | it('should start new clients', function() { 70 | db1 = client.make(__dirname + '/../tmp/c1.sqlite'); 71 | db2 = client.make(__dirname + '/../tmp/c2.sqlite'); 72 | }); 73 | 74 | it('should have c1 make random operations', function(done) { 75 | clientData.randomOps(db1, function(err) { 76 | assert.ok(!err); 77 | done(); 78 | }); 79 | }); 80 | 81 | it('should have c2 make random operations', function(done) { 82 | clientData.randomOps(db2, function(err) { 83 | assert.ok(!err); 84 | done(); 85 | }); 86 | }); 87 | 88 | it('should have server make random operations', function(done) { 89 | serverData.randomOps(server.connection, done); 90 | }); 91 | 92 | it('should sync db1 with the server', function(done) { 93 | syncAndCheck(server.connection, db1, done); 94 | }); 95 | 96 | it('should sync db2 with the server', function(done) { 97 | syncAndCheck(server.connection, db2, done); 98 | }); 99 | 100 | it('should sync db1 with the server', function(done) { 101 | syncAndCheck(server.connection, db1, done); 102 | }); 103 | 104 | it('should have db1 and db2 consistent', function(done) { 105 | checkClients(db1, db2, done); 106 | }); 107 | 108 | it('should have server make random operations again', function(done) { 109 | serverData.randomOps(server.connection, done); 110 | }); 111 | 112 | it('should sync db1 with the server', function(done) { 113 | syncAndCheck(server.connection, db1, done); 114 | }); 115 | 116 | it('should sync db2 with the server', function(done) { 117 | syncAndCheck(server.connection, db2, done); 118 | }); 119 | 120 | it('should have db1 and db2 consistent', function(done) { 121 | checkClients(db1, db2, done); 122 | }); 123 | 124 | it('should end all connections', function() { 125 | db1.close(); 126 | db2.close(); 127 | server.connection.end(); 128 | }); 129 | }); 130 | -------------------------------------------------------------------------------- /lib/client_sync.js: -------------------------------------------------------------------------------- 1 | var async = require('async'); 2 | 3 | // Helper to start SQLite transaction. 4 | 5 | function beginTransaction(db, cb) { 6 | db.run('BEGIN TRANSACTION', cb); 7 | } 8 | 9 | // Helper to stop SQLite transaction. 10 | 11 | function endTransaction(db, cb) { 12 | db.run('COMMIT TRANSACTION', cb); 13 | } 14 | 15 | // Finds all synced tables. 16 | 17 | function findTables(db, cb) { 18 | var sql = 'SELECT tid, name, keycol' + 19 | ' FROM sync_table ORDER BY name'; 20 | db.all(sql, cb); 21 | } 22 | 23 | // Finds deletes on the given table. 24 | // Returns array of key values. 25 | 26 | function findTableDeletes(db, table, cb) { 27 | async.waterfall([ 28 | function(cb) { 29 | var sql = 'SELECT keyval FROM sync' + 30 | ' WHERE action = 1 AND tid = ? ORDER BY keyval'; 31 | db.all(sql, [ table.tid ], cb); 32 | }, 33 | function(rows, cb) { 34 | cb(null, rows.map(function(row) { return row.keyval; })); 35 | } 36 | ], cb); 37 | } 38 | 39 | // Finds table changes. Assumes that the view 40 | // *_changes exists in the database. 41 | 42 | function findTableChanges(db, table, cb) { 43 | var sql = 'SELECT ' + table.name + '.*' + 44 | ' FROM ' + table.name + 45 | ' JOIN sync ON (' + table.name + '.' + table.keycol + ' = sync.keyval)' + 46 | ' WHERE sync.action = 0 AND sync.tid = ?' + 47 | ' ORDER BY ' + table.keycol; 48 | db.all(sql, [ table.tid ], cb); 49 | } 50 | 51 | // Finds both deletes and changes for 52 | // the table. 53 | 54 | function findAllTableChanges(db, table, cb) { 55 | async.waterfall([ 56 | function(cb) { 57 | async.series([ 58 | async.apply(findTableDeletes, db, table), 59 | async.apply(findTableChanges, db, table) 60 | ], cb); 61 | }, 62 | function(results, cb) { 63 | cb(null, { deletes: results[0], changes: results[1] }); 64 | } 65 | ], cb); 66 | } 67 | 68 | // Finds current revision stored on the 69 | // client side. 70 | 71 | function findRev(db, cb) { 72 | var sql = 'SELECT rev FROM revision'; 73 | db.get(sql, function(err, result) { 74 | cb(err, result.rev); 75 | }); 76 | } 77 | 78 | // Finds all changes and the last 79 | // revision number. 80 | // To cb will be passed err, changes 81 | 82 | exports.findChanges = function(db, cb) { 83 | async.series([ 84 | async.apply(findRev, db), 85 | function(cb) { 86 | async.waterfall([ 87 | async.apply(findTables, db), 88 | function(tables, cb) { 89 | var changes = {}; 90 | async.eachSeries(tables, function(table, cb) { 91 | findAllTableChanges(db, table, function(err, tableChanges) { 92 | changes[table.name] = tableChanges; 93 | cb(err); 94 | }); 95 | }, function(err) { 96 | cb(err, changes); 97 | }); 98 | } 99 | ], cb); 100 | } 101 | ], function(err, results) { 102 | var changes = results[1]; 103 | changes.revision = results[0]; 104 | cb(err, changes); 105 | }); 106 | }; 107 | 108 | // Deletes all rows from the given table. 109 | // This is generic convenience function. 110 | // keyvals - array of row keys 111 | // table - name of the table 112 | 113 | function applyTableDeletes(db, keyvals, table, cb) { 114 | async.eachSeries(keyvals, function(keyval, cb) { 115 | if (typeof keyval !== 'string' && typeof keyval !== 'number') { 116 | cb(new Error('Delete key must be a string or a number.')); 117 | } 118 | var sql = 'DELETE FROM ' + table.name + 119 | ' WHERE ' + table.keycol + ' = ?'; 120 | db.run(sql, [ keyval ], cb); 121 | }, cb); 122 | } 123 | 124 | // Applies all changes to the given table. 125 | // This is generic convenience function. 126 | // changes - array on data objects. 127 | // 128 | // The function performs an operation that is also 129 | // known as UPSERT in other database systems. 130 | 131 | function applyTableChanges(db, changes, table, cb) { 132 | async.eachSeries(changes, function(change, cb) { 133 | async.series([ 134 | async.apply(insertOrIgnoreRow, db, change, table), 135 | async.apply(updateRow, db, change, table) 136 | ], cb); 137 | }, cb); 138 | } 139 | 140 | // Creates INSERT OR IGNORE statement for the 141 | // given data object and table. Assumes that 142 | // the data object is completely valid. Does not check. 143 | 144 | function insertOrIgnoreRow(db, data, table, cb) { 145 | var keys = Object.keys(data); 146 | var placeholders = keys.map(function() { return '?'; }); 147 | var params = keys.map(function(key) { return data[key]; }); 148 | var sql = 'INSERT OR IGNORE INTO ' + table.name + 149 | ' (' + keys.join(', ') + ') VALUES (' + placeholders.join(', ') + ')'; 150 | db.run(sql, params, cb); 151 | } 152 | 153 | // Creates UPDATE statement for the given 154 | // data object and the table. Assumes that 155 | // the data object is completely valid. Does not check. 156 | 157 | function updateRow(db, data, table, cb) { 158 | if (typeof data[table.keycol] === 'undefined') { 159 | return cb(new Error('Data object must contain key value property.')); 160 | } 161 | var keys = Object.keys(data); 162 | keys.splice(keys.indexOf(table.keycol), 1); // removes the key column 163 | var updates = keys.map(function(key) { return key + ' = ?'; }); 164 | var params = keys.map(function(key) { return data[key]; }); 165 | params.push(data[table.keycol]); 166 | var sql = 'UPDATE ' + table.name + ' SET ' + updates.join(', ') + 167 | ' WHERE ' + table.keycol + ' = ?'; 168 | db.run(sql, params, cb); 169 | } 170 | 171 | // Removes current sync metadata. 172 | // Used after each successful synchronization 173 | // with the server. 174 | // rev - the last server revision number, sent by the server. 175 | 176 | function resetSync(db, rev, cb) { 177 | async.series([ 178 | function(cb) { db.run('DELETE FROM sync', cb); }, 179 | function(cb) { db.run('UPDATE revision SET rev = ?', [ rev ], cb); } 180 | ], cb); 181 | } 182 | 183 | // changes - object with keys named by tables. 184 | 185 | function applyAllChanges(db, changes, cb) { 186 | async.waterfall([ 187 | async.apply(findTables, db), 188 | function(tables, cb) { 189 | async.eachSeries(tables, function(table, cb) { 190 | async.series([ 191 | async.apply(applyTableChanges, db, changes[table.name].changes || [], table), 192 | async.apply(applyTableDeletes, db, changes[table.name].deletes || [], table) 193 | ], cb); 194 | }, cb); 195 | } 196 | ], cb); 197 | } 198 | 199 | // Applies changes from the server. 200 | // rev - the last server revision number, sent by the server. 201 | 202 | exports.applyChanges = function(db, changes, cb) { 203 | async.series([ 204 | async.apply(beginTransaction, db), 205 | async.apply(applyAllChanges, db, changes), 206 | async.apply(resetSync, db, changes.revision), 207 | async.apply(endTransaction, db) 208 | ], function(err) { 209 | cb(err); 210 | }); 211 | }; -------------------------------------------------------------------------------- /lib/server_sync.js: -------------------------------------------------------------------------------- 1 | var async = require('async'); 2 | var query = require('./server_help').query; 3 | var mysql = require('mysql'); 4 | 5 | // Selects the current timestamp. 6 | 7 | var currentRev = exports.currentRev = function(con, cb) { 8 | var sql = 'SELECT rev FROM revision'; 9 | async.waterfall([ 10 | async.apply(query, con, sql), 11 | function(result, cb) { 12 | cb(null, result[0].rev); 13 | } 14 | ], cb); 15 | }; 16 | 17 | // Finds all synced tables. 18 | 19 | var findTables = exports.findTables = function(con, cb) { 20 | var sql = 'SELECT tid, name, keycol' + 21 | ' FROM sync_table ORDER BY name'; 22 | query(con, sql, cb); 23 | }; 24 | 25 | // Finds all deletes. 26 | 27 | function findTableDeletes(con, since, to, table, cb) { 28 | async.waterfall([ 29 | function(cb) { 30 | var sql = 'SELECT keyval FROM sync' + 31 | ' WHERE action = 1 AND rev > ? AND rev <= ?' + 32 | ' AND tid = ? ORDER BY keyval'; 33 | var params = [ since, to, table.tid ]; 34 | query(con, sql, params, cb); 35 | }, 36 | function(results, cb) { 37 | cb(null, results.map(function(row) { return row.keyval; })); 38 | } 39 | ], cb); 40 | } 41 | 42 | // Finds all changes for the given table. 43 | // This uses mysql.escapeId() function to 44 | // safely handle dynamic table and column names. 45 | 46 | function findTableChanges(con, since, to, table, cb) { 47 | var sql = 'SELECT ' + mysql.escapeId(table.name) + '.*' + 48 | ' FROM ' + mysql.escapeId(table.name) + 49 | ' JOIN sync ON (' + mysql.escapeId(table.name) + 50 | '.' + mysql.escapeId(table.keycol) + ' = sync.keyval)' + 51 | ' WHERE sync.action = 0 AND sync.rev > ?' + 52 | ' AND sync.rev <= ?' + 53 | ' AND sync.tid = ? ORDER BY ' + mysql.escapeId(table.keycol); 54 | var params = [ since, to, table.tid ]; 55 | query(con, sql, params, cb); 56 | } 57 | 58 | // Finds both deletes and changes for 59 | // the table. 60 | 61 | function findAllTableChanges(con, since, to, table, cb) { 62 | async.waterfall([ 63 | function(cb) { 64 | async.series([ 65 | async.apply(findTableDeletes, con, since, to, table), 66 | async.apply(findTableChanges, con, since, to, table) 67 | ], cb); 68 | }, 69 | function(results, cb) { 70 | cb(null, { deletes: results[0], changes: results[1] }); 71 | } 72 | ], cb); 73 | } 74 | 75 | // Finds all changes. 76 | 77 | var findChanges = exports.findChanges = function(con, since, to, tables, cb) { 78 | var changes = {}; 79 | async.eachSeries(tables, function(table, cb) { 80 | findAllTableChanges(con, since, to, table, function(err, tableChanges) { 81 | changes[table.name] = tableChanges; 82 | cb(err); 83 | }); 84 | }, function(err) { 85 | cb(err, changes); 86 | }); 87 | }; 88 | 89 | // Creates INSERT ... ON DUPLICATE KEY UPDATE statement 90 | // for the given data object and table. Assumes that 91 | // the data object is completely valid. Does not check. 92 | 93 | function insertOrUpdateRow(con, data, table, cb) { 94 | if (!data.hasOwnProperty(table.keycol)) { 95 | return cb(new Error('Data object has no key field.')); 96 | } 97 | var keys = Object.keys(data); 98 | var placeholders = keys.map(function() { return '?'; }); 99 | var params = keys.map(function(key) { return data[key]; }); 100 | var updates = keys.slice(0); 101 | updates.splice(keys.indexOf(table.keycol), 1); 102 | function updateByColVal(col) { 103 | return mysql.escapeId(col) + ' = VALUES(' + mysql.escapeId(col) + ')'; 104 | } 105 | var sql = 'INSERT INTO ' + mysql.escapeId(table.name) + '(' + 106 | keys.map(mysql.escapeId).join(', ') + ') VALUES (' + placeholders.join(', ') + ')' + 107 | ' ON DUPLICATE KEY UPDATE ' + updates.map(updateByColVal).join(', '); 108 | query(con, sql, params, cb); 109 | } 110 | 111 | // Deletes all rows from the given table. 112 | // This is generic convenience function. 113 | // uuids - array of row keys 114 | // table - name of the table 115 | 116 | function applyTableDeletes(con, uuids, table, cb) { 117 | if (!Array.isArray(uuids)) { 118 | return cb(new Error('First argument must be an array.')); 119 | } 120 | console.log('Table %s has %s deletes.', table.name, uuids.length); 121 | async.eachSeries(uuids, function(uuid, cb) { 122 | if (typeof uuid !== 'string' && typeof uuid !== 'number') { 123 | return cb(new Error('Key must be a string or a number.')); 124 | } 125 | var sql = 'DELETE FROM ' + mysql.escapeId(table.name) + 126 | ' WHERE ' + mysql.escapeId(table.keycol) + ' = ?'; 127 | query(con, sql, [ uuid ], cb); 128 | }, cb); 129 | } 130 | 131 | // Applies all changes to the given table. 132 | // This is generic convenience function. 133 | // changes - array on data objects. 134 | 135 | function applyTableChanges(con, changes, table, cb) { 136 | console.log('Table %s has %s changes.', table.name, changes.length); 137 | async.eachSeries(changes, function(change, cb) { 138 | insertOrUpdateRow(con, change, table, cb); 139 | }, cb); 140 | } 141 | 142 | // changes - object with keys named by tables. 143 | 144 | function applyAllChanges(con, changes, tables, cb) { 145 | async.eachSeries(tables, function(table, cb) { 146 | async.series([ 147 | async.apply(applyTableChanges, con, changes[table.name].changes || [], table), 148 | async.apply(applyTableDeletes, con, changes[table.name].deletes || [], table) 149 | ], cb); 150 | }, cb); 151 | } 152 | 153 | function lockTables(con, tables, cb) { 154 | var tableLocks = tables.map(function(table) { 155 | return mysql.escapeId(table.name) + ' WRITE'; 156 | }).join(', '); 157 | query(con, 'LOCK TABLES sync_table READ, sync WRITE, ' + tableLocks, cb); 158 | } 159 | 160 | // Unlocks all currently held table locks. 161 | 162 | function unlockTables(con, cb) { 163 | query(con, 'UNLOCK TABLES', cb); 164 | } 165 | 166 | // Synchronizes client data with the server data. 167 | // cb must accept rev and changes. 168 | 169 | exports.sync = function(con, changes, cb) { 170 | var crrev, nwrev, outchanges, tables; 171 | var start = Date.now(); 172 | var clrev = changes.revision; 173 | console.log('Client revision: %s', clrev); 174 | async.series([ 175 | function(cb) { 176 | // Finds the names of tables that have to be synced. 177 | findTables(con, function(err, results) { 178 | tables = results; 179 | console.log('Synced tables: %s', tables.map(function(table) { return table.name; }).join(', ')); 180 | cb(err); 181 | }); 182 | }, 183 | function(cb) { 184 | // Locks tables. Prevents updates by other 185 | // connections. 186 | lockTables(con, tables, cb); 187 | }, 188 | function(cb) { 189 | // Finds the current server revision. 190 | currentRev(con, function(err, rev) { 191 | console.log('Server revision before sync: ' + rev); 192 | crrev = rev; 193 | cb(err); 194 | }); 195 | }, 196 | function(cb) { 197 | // Applies all changes from the client. 198 | applyAllChanges(con, changes, tables, cb); 199 | }, 200 | function(cb) { 201 | // Finds current revision on the server. 202 | // This is sent back to the client. 203 | currentRev(con, function(err, rev) { 204 | console.log('Server revision after sync: ' + rev); 205 | nwrev = rev; 206 | cb(err); 207 | }); 208 | }, 209 | function(cb) { 210 | // Finds changes on the server that were made 211 | // before the current syncing session. 212 | findChanges(con, clrev, crrev, tables, function(err, results) { 213 | outchanges = results; 214 | tables.forEach(function(table) { 215 | console.log('Table %s outgoing changes: %s', table.name, outchanges[table.name].changes.length); 216 | console.log('Table %s outgoing deletes: %s', table.name, outchanges[table.name].deletes.length); 217 | }); 218 | cb(err); 219 | }); 220 | } 221 | ], function(err) { 222 | // Unlocks tables. 223 | unlockTables(con, function(lerr) { 224 | console.log('Syncing took: %s ms', (Date.now() - start)); 225 | outchanges.revision = nwrev; 226 | cb(err || lerr, outchanges); 227 | }); 228 | }); 229 | }; -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | sql-sync 2 | ======== 3 | 4 | Offline replication between SQLite (clients) and MySQL (master). This 5 | project is not a library, rather it is example code. Some parts of it 6 | (code in `lib`) could be reused in other projects. The code mainly 7 | just tests that the approach described here works. The code is built 8 | for Node.JS. 9 | 10 | Assumes the following: 11 | 12 | * Primary keys are [UUIDs](http://en.wikipedia.org/wiki/Uuid) (here 36-character strings); 13 | * No foreign key constraints. 14 | 15 | It is possible to use foreign key constraints but then table 16 | updates must be reordered correctly (complicates the code a lot!). 17 | 18 | It is possible to use [natural keys](http://en.wikipedia.org/wiki/Natural_key) 19 | instead of UUIDs but there do not always exist good natural keys. 20 | In most cases large composite keys would have to be used. 21 | It is not possible to use autoincremented keys because of key value conflicts. 22 | 23 | Metainfo 24 | -------- 25 | 26 | On the client side table actions (INSERT/UPDATE/DELETE) are recorded 27 | into the metadata table `sync` with the following structure: 28 | 29 | CREATE TABLE sync ( 30 | action INTEGER NOT NULL, 31 | keyval CHARACTER(36) NOT NULL, 32 | tid INTEGER NOT NULL, 33 | PRIMARY KEY (keyval) ON CONFLICT REPLACE 34 | ); 35 | 36 | In the table: 37 | 38 | * action - 0 marks insert/update, 1 marks delete; 39 | * keyval - primary key value in the row; 40 | * tid - table id (used by triggers below). 41 | 42 | Synced tables are kept in the table `sync_table`: 43 | 44 | CREATE TABLE sync_table ( 45 | tid INTEGER NOT NULL, 46 | name VARCHAR(255) NOT NULL, 47 | keycol VARCHAR(255) NOT NULL, 48 | PRIMARY KEY (tid), 49 | UNIQUE (name) 50 | ); 51 | 52 | In the table: 53 | 54 | * tid - table id. 55 | * name - table name. 56 | * keycol - name of primary key column in the table. 57 | 58 | For each table in `sync_table` the following triggers have 59 | to be created: 60 | 61 | CREATE TRIGGER