├── package.json ├── readme.md ├── rosettable.js ├── runtests_mysql.sql ├── runtests_pg.sql ├── sample.rosettable.conf ├── setupandtest.sh ├── setuptest_mysql_create_test_schema.sql ├── setuptest_pg_import_fdw_create_triggers.sql ├── testexp_mysql_then_pg └── testexp_pg_then_mysql /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "rosettable", 3 | "version": "1.0.0", 4 | "description": "watch mysql binlog to fire appropriate postgres triggers", 5 | "main": "index.js", 6 | "scripts": { 7 | "test": "echo \"Error: no test specified\" && exit 1" 8 | }, 9 | "author": "Francois Payette", 10 | "license": "GPL", 11 | "dependencies": { 12 | "async-lock": "^1.2.2", 13 | "pg": "^8.0.0", 14 | "zongji": "^0.5.1" 15 | } 16 | } 17 | -------------------------------------------------------------------------------- /readme.md: -------------------------------------------------------------------------------- 1 | ## Rationale for Rosettable 2 | 3 | Wouldn't it be nice if we were over C19? Ok well in the mean time here's a hack that you might like (and a [song](https://www.youtube.com/watch?v=lD4sxxoJGkA) to cheer you up while you read this): 4 | 5 | Postgres is the awesomest RDBMS out there, with some really cool stuff baked in --stored procedures in many languages, triggers, JSON-native, pubsub like pg_notify etc...(last with postgraphile/GraphQL is simply soo... sublime). 6 | 7 | Yet a lot of great open-source software developers have chosen mysql/mariadb/mongodb over it in the past. Personal choices cannot be discussed. So to contribute to these nice software projects (mailtrain, matomo, etc) you have to do the LAMP dance... That might turn you off, social distancing and all. You could use [pgchameleon](https://pgchameleon.org/), but that only works one way, mysql to postgres, and you now have to two copies of everything. And you now have to two copies of everything. 8 | 9 | Not so fast! Postgres allows you to interact both read and write with the data in these datastores (and more!) as if they were in postgres using Foreign Data Wrappers: FDW for de world! 10 | 11 | There's one thing, though. If you are a postgres aficionado, you most likely love triggers. Say you connect to a foreign mysql schema in postgres: 12 | 13 | ``` 14 | CREATE USER MAPPING FOR yourpguser SERVER mysql_server OPTIONS (username 'mysqluser', password 'mysqlpass'); 15 | create schema mysql_msqldatabase; 16 | IMPORT FOREIGN SCHEMA msqldatabase FROM SERVER mysql_server INTO mysql_msqldatabase; 17 | ``` 18 | 19 | You can define triggers on your IMPORTed FOREIGN SCHEMA. Niiice! So say you add a trigger to a foreign data table named employee. When you UPDATE a row in employee via a postgres connection, your trigger will get called. Yay! But what if a table is modified via an app that has a connection to the mysqld, not to your shinny new postgres FDW? 20 | 21 | No triggers for you... 😢 22 | 23 | This is where this hack comes in!!! 👍 😛 24 | 25 | Using mysql's binlog(thru a cool evt reader call zongji) and a few schema queries this node app will fire your postgres PLPgSQL triggers for you! (well not really, it repackages and executes your triggers' code post-commit) 26 | 27 | But, you ask, what if I modified the NEW row in the before trigger? Or set it to NULL to prevent the operation? Well that works too! The post-before value of NEW is compared with the pre-value and silent UPDATES are issued. There's a 80% chance of bugs with this BEFORE pg trigger business, please report. 28 | 29 | ## Caveat 30 | 31 | This app adds an optional column named pgrti on the fly to any mysql table for which you add a trigger in your postgres foreign schema. This means that if you have inserts that do not specify the columns in your MySQL schema you'll need to edit some statements; for example: 32 | 33 | ``` 34 | INSERT INTO employee VALUES (DEFAULT, 'MYSQLINSERT--',2); 35 | ``` 36 | needs to change to: 37 | ``` 38 | INSERT INTO employee(emp_id,emp_name,emp_dept_id) VALUES (DEFAULT, 'MYSQLINSERT--',2); 39 | ``` 40 | 41 | ## Minor annoyances 42 | 43 | The current mysql_fdw (2.5) has a few limitations, text fields over 64K will cause the FDW to go haywire, and camelCase tableNames might or might not work, depending on your mysql default settings ( by default they will not IIRC ). I might fix these in the fork mentionned below. 44 | 45 | ## How to test/use 46 | 47 | ~~0. This requires a small bugfix that has not made it yet to the MySQL FDW distribution. Please get it here: https://github.com/francoisp/mysql_fdw~~ 48 | mysql_fdw has been updated! If you have version 2.5.5 you are good to go! 49 | 50 | ~~ 51 | ``` 52 | --follow instructions to make and install the updated myslq_fdw -- for now --. Hopefully the PR will merge upstream soon 53 | ``` 54 | ~~ 55 | 1. Enable MySQL binlog in my.cnf (ubuntu:/etc/mysql/my.cnf YMMV), restart MySQL server after making these changes. 56 | ``` 57 | # add the mysqld block is you dont have it, otherwise you can add the rest of the config under your existing block 58 | [mysqld] 59 | # Must be unique integer from 1-2^32 60 | server-id = 1 61 | # Row format required for ZongJi, the very nice binlog parser used 62 | binlog_format = row 63 | # Directory must exist. This path works for Linux. Other OS may require 64 | # different path. 65 | log_bin = /var/log/mysql/mysql-bin.log 66 | 67 | binlog_do_db = employees # Optional, limit which databases to log 68 | expire_logs_days = 10 # Optional, purge old logs 69 | max_binlog_size = 100M # Optional, limit log size 70 | ``` 71 | 72 | 2. clone this repo and get dependencies (tested with node 0.10): 73 | ``` 74 | git clone https://github.com/francoisp/rosettable.git 75 | cd rosettable 76 | npm i 77 | ``` 78 | 3. run all test (testing assumes mysql>=5.7 and postgres>=11 running on localhost for simplicity, look at rosettable.js for the connection strings) This creates a database and mapping and some tests triggers and runs some tests. 79 | ``` 80 | bash ./setupandtest.sh --mysqlrootpass $mysqlrootpass --postgresport $postgresport --postgresuser $PGUSERWITHSUPER --postgrespass $PGUSERPASS 81 | ``` 82 | 83 | To use in your project, you'll need to fiddle a bit: you need to add a user to your mysql db, give it replication rights, and put those credentials as well as creds to your posgres db in a rosettable.conf file and run this as a seperate process, with (if you start to dig this you should use pm2): 84 | ``` 85 | node rosettable.js 86 | ``` 87 | 88 | 89 | A webservice might be coming next. Please let me know if this is useful, cheerio, stay safe.: [🌈]( https://www.youtube.com/watch?v=zsk6z9O1WmE) 90 | 91 | PS: I'm releasing this under the GPL. If your commercial project could use this, let me know. We can do a support contract and/or a special license, or MIT. 92 | 93 | PPS: Same if you'd like to see a version for MongoDB, Oracle, MSSQL etc, please get in touch we'll work something out. 94 | -------------------------------------------------------------------------------- /rosettable.js: -------------------------------------------------------------------------------- 1 | // Client code 2 | const ZongJi = require('zongji'); 3 | const pg = require('pg'); 4 | var mysql1 = require('mysql'); 5 | var AsyncLock = require('async-lock'); 6 | 7 | var lock = new AsyncLock(); 8 | var fs = require('fs'), 9 | 10 | 11 | //we could watch more than one schema at once with zongji, or have sepearate deamons 12 | //mysqldbwatched='mqltestdb'; 13 | 14 | zongji_conf = { 15 | host : 'localhost', 16 | user : 'rosettableD', 17 | password : 'pointandshoot', 18 | }; 19 | 20 | 21 | pgconfig = { 22 | user: 'fdw_user', 23 | password: 'this_1s_fdw_us3r', 24 | host: 'localhost', 25 | port: '5432', 26 | database: 'testdb_pg' 27 | }; 28 | 29 | 30 | mysqlELEVATEDconfig = { 31 | multipleStatements: true, 32 | host : 'localhost', 33 | user : 'rosettableAdm', 34 | password : 'admpasswatchout', 35 | database: 'mqltestdb', 36 | waitForConnections: true, 37 | connectionLimit: 10, 38 | queueLimit: 0 39 | }; 40 | 41 | mysqlconfig = { 42 | multipleStatements: true, 43 | host : 'localhost', 44 | user : 'rosettableU', 45 | password : 'pointandshoot2', 46 | database: 'mqltestdb', 47 | waitForConnections: true, 48 | connectionLimit: 10, 49 | queueLimit: 0 50 | }; 51 | 52 | 53 | configPath = __dirname +'/notversioned.rosettable.conf'; 54 | if(fs.existsSync(configPath)) 55 | { 56 | console.log("READING rosettable CONFIGURATION, NOT INTEGRATED TESTING") 57 | var parsed = JSON.parse(fs.readFileSync(configPath, 'UTF-8')); 58 | zongji_conf = parsed.zongji_conf; 59 | pgconfig = parsed.pgconfig; 60 | mysqlconfig = parsed.mysqlconfig; 61 | mysqlELEVATEDconfig = parsed.mysqlELEVATEDconfig; 62 | }else 63 | console.log("WARNINGL DID NOT READ CONFIG FILE: INTEGRATED TESTING") 64 | 65 | 66 | const zongji = new ZongJi(zongji_conf); 67 | const pgpool = new pg.Pool(pgconfig); 68 | const mysqlpool = mysql1.createPool(mysqlconfig); 69 | 70 | 71 | function logwithoutrecursion(objpar) 72 | { 73 | // use this to print a recursive stucture 74 | var cache = []; 75 | console.log(JSON.stringify(objpar, function(key, value) { 76 | if (typeof value === 'object' && value !== null) { 77 | if (cache.indexOf(value) !== -1) { 78 | // Duplicate reference found, discard key 79 | return; 80 | } 81 | // Store value in our collection 82 | cache.push(value); 83 | } 84 | return value; 85 | }, 4)); 86 | cache = null; // Enable garbage collection 87 | 88 | } 89 | 90 | 91 | function isSame(a,b) { 92 | if(a.length != b.length){ 93 | 94 | return false; 95 | } 96 | if(a.filter(function(i) {return a.indexOf(i) < 0;}).length > 0){ 97 | 98 | return false; 99 | } 100 | if(b.filter(function(i) {return a.indexOf(i) < 0;}).length > 0) 101 | return false; 102 | return true; 103 | }; 104 | function subtract(a, b) { 105 | var r = {}; 106 | 107 | // For each property of 'b' 108 | // if it's different than the corresponding property of 'a' 109 | // place it in 'r' 110 | for (var key in b) { 111 | if (Array.isArray(b[key])) { 112 | if(!a[key]) a[key] = []; 113 | if(!isSame(a[key],b[key])) 114 | r[key] = a[key]; 115 | } else if (typeof(b[key]) == 'object' && b[key] != null && a[key] != null) { 116 | if(Object.prototype.toString.call(b[key]) === '[object Date]' && Object.prototype.toString.call(a[key]) === '[object Date]'){ 117 | if(b[key].getTime() != a[key].getTime()) 118 | r[key] = a[key] 119 | // a Date object is instantiated with a before trigger, but the orig is still a String 120 | }else if(Object.prototype.toString.call(b[key]) === '[object Date]'){ 121 | //we instantiate a Date and compare 122 | if(b[key].getTime() != (new Date(a[key])).getTime()) 123 | r[key] = a[key] 124 | 125 | }else{ 126 | if (!a[key]) a[key] = {}; 127 | r[key] = subtract(a[key], b[key]); 128 | } 129 | } else { 130 | if (b[key] != a[key]) { 131 | r[key] = a[key]; 132 | } 133 | } 134 | } 135 | return r; 136 | } 137 | 138 | function sleep(ms) { 139 | return new Promise(resolve => setTimeout(resolve, ms)); 140 | } 141 | 142 | 143 | async function addpgrti_pg(foreignschemas,tableName,pgclient) 144 | { 145 | for (var i = 0; i < foreignschemas.length; i++) { 146 | foreignschemas[i] 147 | await pgclient.query(` 148 | alter FOREIGN table `+foreignschemas[i]+`.`+tableName+` add IF NOT EXISTS pgrti bigint DEFAULT NULL; 149 | 150 | CREATE OR REPLACE FUNCTION aaatrig_upins_pgrti() returns trigger 151 | AS $$ 152 | DECLARE 153 | BEGIN 154 | -- this check is in case this trigger gets called before the pgrti col is added. May happen on database restore for example 155 | IF NOT(row_to_json(NEW)->'pgrti' is NULL) THEN 156 | -- there is as a non zero chance the update trigger can be fired twice... 157 | -- there is also a strange bug that on BEFORE INSERT the NEW.pgrti gets 0 instead of a random! 158 | NEW.pgrti = (9223372036854773427*random()); 159 | 160 | END IF; 161 | --RAISE LOG 'aaatrig_upins_pgrti'; 162 | --RAISE NOTICE 'aaatrig_upins_pgrti %', row_to_json(NEW)::text; 163 | return NEW; 164 | 165 | END; 166 | $$ LANGUAGE plpgsql; 167 | 168 | CREATE OR REPLACE FUNCTION aaatrig_del_pgrti() returns trigger 169 | AS $$ 170 | DECLARE 171 | trigrow json; 172 | whereClause text DEFAULT 'WHERE '; 173 | key text; 174 | value text; 175 | msg jsonb; 176 | BEGIN 177 | trigrow = row_to_json(OLD); 178 | --RAISE NOTICE 'trigrow:%',trigrow; 179 | -- this check is in case this trigger gets called before the pgrti col is added. May happen on database restore for example 180 | IF NOT(trigrow->'pgrti' is NULL) THEN 181 | msg = ('{"fdw_schema":"'||TG_TABLE_SCHEMA||'","tablename":"'||TG_TABLE_NAME||'","pgrti":"'||(OLD.pgrti)::text||'"}')::jsonb; 182 | PERFORM pg_notify('pg_silent_del',msg::text); 183 | END IF; 184 | --RAISE LOG 'aaatrig_del_pgrti'; 185 | --RAISE NOTICE 'aaatrig_del_pgrti %', row_to_json(OLD)::text; 186 | return OLD; 187 | 188 | END; 189 | $$ LANGUAGE plpgsql; 190 | DROP TRIGGER IF EXISTS aaatrigup_pgrti ON `+foreignschemas[i]+`.`+tableName+`; 191 | DROP TRIGGER IF EXISTS aaatrigins_pgrti ON `+foreignschemas[i]+`.`+tableName+`; 192 | DROP TRIGGER IF EXISTS aaatrigdel_pgrti ON `+foreignschemas[i]+`.`+tableName+`; 193 | CREATE TRIGGER aaatrigup_pgrti BEFORE UPDATE ON `+foreignschemas[i]+`.`+tableName+` FOR EACH ROW EXECUTE PROCEDURE aaatrig_upins_pgrti(); 194 | CREATE TRIGGER aaatrigins_pgrti BEFORE INSERT ON `+foreignschemas[i]+`.`+tableName+` FOR EACH ROW EXECUTE PROCEDURE aaatrig_upins_pgrti(); 195 | CREATE TRIGGER aaatrigdel_pgrti BEFORE DELETE ON `+foreignschemas[i]+`.`+tableName+` FOR EACH ROW EXECUTE PROCEDURE aaatrig_del_pgrti(); 196 | `); 197 | } 198 | } 199 | 200 | // acting as a very simple mutex, node is single threaded ans we should have a single instance of this deamon running 201 | var addingpgrtimutex = false; 202 | async function addpgrti(evtrow,foreignschemas,tableName,pgclient, pg_only = false) 203 | { 204 | // lets first try to catch any ongoing udpate operations -- this is transient and not garranteed, if we dont catch an update issued from pg we'll get the triggers fired twice (this could occur only on first event); 205 | // maybe this could run inside the mysql_fdw, that way w'd be garanteed to be in transaction? but where would we put the results? 206 | // var alltxsQ = `select json_agg(pgstat.query) from (select * from pg_stat_activity where datname = '`+pgconfig.database+`' AND query ILIKE '%`+tableName+`%' AND 207 | // query not like 'select json_agg(pgstat.query) from (select%' AND 208 | // query not like 'select json_agg(procs) as procs%' AND 209 | // query not like '%alter FOREIGN table %`+tableName+`% add pgrti%' 210 | // ) as pgstat;`; 211 | // const alltxs = await pgclient.query(alltxsQ); 212 | // console.log('ALLTXS:'+JSON.stringify(alltxs.rows[0].json_agg)); 213 | // // if we have on ongoing tx in postgres for this table we'll assume this initial event orginated in postgres. 214 | // // this is not 100 fool proof, there's a chance the tx is over because of some lag, but we are doing our best to 215 | // // not fire the trigger twice 216 | // if(alltxs.rows[0].json_agg != null){ 217 | // // by setting the pgrti here we are identifying this initial operation as a postgres issued op 218 | // evtrow.pgrti = 42; 219 | // console.log('SET TO NOT RUN TRIGGERS, INITIAL CRUD COMMING FROM PG') 220 | // } 221 | // this is a critical section, we only want to add the pgrti col and triggers once 222 | lock.acquire('addpgrti', async function() { 223 | 224 | if(addingpgrtimutex == false) 225 | { 226 | 227 | addingpgrtimutex = true; 228 | 229 | 230 | if(pg_only == false){ 231 | console.log("ALTERING SCHEMAS TO ADD A PGRTI COL AND TRIGGERS TO BOTH SIDES") 232 | // this is the first time we see an update on this table, we'll add our special field to this table in mysql 233 | // use other mysql client, mysql2 client has a problem with the schema mod? 234 | var connection = mysql1.createConnection(mysqlELEVATEDconfig); 235 | connection.connect(); 236 | //-- if we have null the insert came via mysqld. insert via pg will have positive val 237 | //-- having a non null value allows us to distinguish never pg-altered deletes without using id col 238 | var mysqladdpgrti = `LOCK TABLES `+tableName+` WRITE; ALTER TABLE `+tableName+` ADD pgrti BIGINT DEFAULT NULL; SET GLOBAL log_bin_trust_function_creators = 1; DROP TRIGGER IF EXISTS aaabefore_`+tableName+`_insert; CREATE TRIGGER aaabefore_`+tableName+`_insert BEFORE INSERT ON `+tableName+` FOR EACH ROW BEGIN IF NEW.pgrti is NULL THEN SET NEW.pgrti = -(9223372036854773427*RAND()); END IF; END ; UNLOCK TABLES;`; 239 | connection.query(mysqladdpgrti, async function (error, results, fields) { 240 | if (error) throw error; 241 | 242 | addpgrti_pg(foreignschemas,tableName,pgclient) 243 | 244 | }); 245 | 246 | connection.end(); 247 | }else{ 248 | console.log("ALTERING POSTGRES SCHEMAS TO ADD A PGRTI COL AND TRIGGERS --foreign schema was dropped?") 249 | addpgrti_pg(foreignschemas,tableName,pgclient) 250 | } 251 | 252 | // this is very weird and a hack, if we dont slow down a bit, the actual event that triggerd adding pgrti will not see the new col 253 | await sleep(100); 254 | console.log("DONE ALTERING SCHEMAS"); 255 | addingpgrtimutex = false; 256 | } 257 | }); 258 | } 259 | 260 | 261 | 262 | function pgsql_storedProcsQuery(evt,event_manipulation,action_timing) 263 | { 264 | //regexp_replace(regexp_replace(prosrc, '([\\\s|;])--[^\\\n]*', '\\1', 'g'), '([\\\s|;])RETURN(\\\s)+[^;]+;', '\\1', 'ig') 265 | var pgsql_storedProcs = `select json_agg(procs) as procs, json_agg(foreignschemas) as foreignschemas from ( 266 | select regexp_replace(prosrc, '([\\\s|;])--[^\\\n]*', '\\1', 'g') as prosrc,foreign_table_schema as foreignschema, information_schema.triggers.trigger_name as trigger_name,information_schema.triggers.action_timing as action_timing, information_schema.triggers.action_statement as action_statement from 267 | ( 268 | select distinct foreign_table_schema from information_schema.foreign_table_options WHERE 269 | information_schema.foreign_table_options.foreign_table_catalog = '`+pgconfig.database+`' AND 270 | information_schema.foreign_table_options.option_name = 'dbname' AND 271 | information_schema.foreign_table_options.option_value = '`+evt.tableMap[evt.tableId].parentSchema+`') as foreign_table_schema, 272 | information_schema.triggers,pg_proc WHERE 273 | information_schema.triggers.event_object_schema = foreign_table_schema AND 274 | information_schema.triggers.event_object_table = '`+evt.tableMap[evt.tableId].tableName+`' AND 275 | information_schema.triggers.event_manipulation = '`+event_manipulation.toUpperCase()+`' AND`; 276 | if( !(action_timing === undefined)) 277 | pgsql_storedProcs+=`information_schema.triggers.action_timing = '`+action_timing.toUpperCase()+`' AND`; 278 | pgsql_storedProcs+=` 279 | information_schema.triggers.action_orientation = 'ROW' AND 280 | ( pg_proc.proname = split_part(regexp_replace(action_statement, 'EXECUTE PROCEDURE\\\s+', ''),'(',1) OR 281 | pg_proc.proname = split_part(regexp_replace(action_statement, 'EXECUTE FUNCTION\\\s+', ''),'(',1)) AND 282 | pg_proc.proname NOT LIKE '%_pgrti' 283 | ORDER BY information_schema.triggers.action_timing,information_schema.triggers.action_order) as procs, 284 | (select json_object_agg(foreign_table_schema, cols) as foreignschemas from (select foreign_table_schema, json_object_agg(information_schema.columns.column_name, information_schema.columns.data_type) as cols from information_schema.foreign_table_options,information_schema.columns WHERE 285 | information_schema.foreign_table_options.foreign_table_schema = information_schema.columns.table_schema AND 286 | information_schema.foreign_table_options.foreign_table_catalog = '`+pgconfig.database+`' AND 287 | information_schema.foreign_table_options.foreign_table_name = '`+evt.tableMap[evt.tableId].tableName+`' AND 288 | information_schema.columns.table_name = '`+evt.tableMap[evt.tableId].tableName+`' AND 289 | information_schema.foreign_table_options.option_name = 'dbname' AND 290 | information_schema.foreign_table_options.option_value = '`+mysqlconfig.database+`' group by foreign_table_schema) as fschemas) as foreignschemas 291 | ; 292 | `; 293 | //console.log(pgsql_storedProcs); 294 | return pgsql_storedProcs; 295 | } 296 | 297 | 298 | function pgsql_storedALLProcsQuery(evt,event_manipulation,action_timing) 299 | { 300 | //regexp_replace(regexp_replace(prosrc, '([\\\s|;])--[^\\\n]*', '\\1', 'g'), '([\\\s|;])RETURN(\\\s)+[^;]+;', '\\1', 'ig') 301 | var pgsql_storedProcs = `select json_object_agg(proname,procs) as storedprocs, json_agg(foreignschemas) as foreignschemas from ( 302 | select regexp_replace(prosrc, '([\\\s|;])--[^\\\n]*', '\\1', 'g') as prosrc,proname,foreign_table_schema as foreignschema, information_schema.triggers.trigger_name as trigger_name,information_schema.triggers.action_timing as action_timing, information_schema.triggers.action_statement as action_statement from 303 | ( 304 | select distinct foreign_table_schema from information_schema.foreign_table_options WHERE 305 | information_schema.foreign_table_options.foreign_table_catalog = '`+pgconfig.database+`' AND 306 | information_schema.foreign_table_options.option_name = 'dbname' AND 307 | information_schema.foreign_table_options.option_value = '`+evt.tableMap[evt.tableId].parentSchema+`') as foreign_table_schema, 308 | information_schema.triggers,pg_proc WHERE 309 | information_schema.triggers.event_object_schema = foreign_table_schema AND 310 | information_schema.triggers.event_object_table = '`+evt.tableMap[evt.tableId].tableName+`' AND 311 | information_schema.triggers.event_manipulation = '`+event_manipulation.toUpperCase()+`' AND`; 312 | if( !(action_timing === undefined)) 313 | pgsql_storedProcs+=`information_schema.triggers.action_timing = '`+action_timing.toUpperCase()+`' AND`; 314 | pgsql_storedProcs+=` 315 | information_schema.triggers.action_orientation = 'ROW' AND 316 | ( pg_proc.proname = split_part(regexp_replace(action_statement, 'EXECUTE PROCEDURE\\\s+', ''),'(',1) OR 317 | pg_proc.proname = split_part(regexp_replace(action_statement, 'EXECUTE FUNCTION\\\s+', ''),'(',1)) 318 | ORDER BY information_schema.triggers.action_timing,information_schema.triggers.action_order) as procs, 319 | (select json_object_agg(foreign_table_schema, cols) as foreignschemas from (select foreign_table_schema, json_object_agg(information_schema.columns.column_name, information_schema.columns.data_type) as cols from information_schema.foreign_table_options,information_schema.columns WHERE 320 | information_schema.foreign_table_options.foreign_table_schema = information_schema.columns.table_schema AND 321 | information_schema.foreign_table_options.foreign_table_catalog = '`+pgconfig.database+`' AND 322 | information_schema.foreign_table_options.foreign_table_name = '`+evt.tableMap[evt.tableId].tableName+`' AND 323 | information_schema.columns.table_name = '`+evt.tableMap[evt.tableId].tableName+`' AND 324 | information_schema.foreign_table_options.option_name = 'dbname' AND 325 | information_schema.foreign_table_options.option_value = '`+mysqlconfig.database+`' group by foreign_table_schema) as fschemas) as foreignschemas 326 | ; 327 | `; 328 | 329 | 330 | //console.log(pgsql_storedProcs); 331 | return pgsql_storedProcs; 332 | } 333 | 334 | async function pgsql_storedProcsAsync(pgclient, evt,event_manipulation,action_timing) 335 | { 336 | var result = {pgrti:false}; 337 | var pgsql_storedProcs = pgsql_storedALLProcsQuery(evt,event_manipulation,action_timing); 338 | const res = await pgclient.query(pgsql_storedProcs); 339 | if(res.rows.length > 0 && res.rows[0].storedprocs != undefined) 340 | { 341 | var row = res.rows[0]; 342 | //console.log(JSON.stringify(res.rows[0])); 343 | for (const [key, value] of Object.entries(row.storedprocs)) 344 | { 345 | if(key.endsWith('_pgrti')) 346 | result.pgrti = true; 347 | else 348 | { 349 | if(result.procs == undefined) 350 | result.procs = []; 351 | result.procs.push(value); 352 | } 353 | } 354 | result.foreignschemas = row.foreignschemas; 355 | } 356 | return result; 357 | } 358 | // 359 | 360 | // function pgsql_fakeROW(row, name) 361 | // { 362 | // var fakeROW = '\nBEGIN\n SELECT '; 363 | // for (var key in row) { 364 | // var val = row[key]; 365 | // if(Object.prototype.toString.call(val) === '[object Date]') 366 | // val = val.toISOString(); 367 | // if(val != null && !Number.isInteger(val)) 368 | // val = '\''+ val+'\''; 369 | // fakeROW = ' ' + fakeROW + val + ' as '+ key + ','; 370 | // } 371 | // fakeROW = fakeROW.replace(/,+$/, "") + ' into '+name+';'; 372 | // return fakeROW; 373 | // } 374 | 375 | function pgsql_fakeREC(row,tablestruc) 376 | { 377 | var fakeROW = 'SELECT '; 378 | for (var key in row) { 379 | var val = row[key]; 380 | if(Object.prototype.toString.call(val) === '[object Date]') 381 | val = val.toISOString(); 382 | if(val != null && !Number.isInteger(val)) 383 | val = '\''+ val+'\''; 384 | //bugfix: if we have a missing row type, it's most likely pgrti that has just been added 385 | var rowtype ='bigint'; 386 | if(typeof tablestruc[key] != 'undefined') 387 | rowtype = tablestruc[key]; 388 | fakeROW = ' ' + fakeROW + val + '::'+rowtype+' as '+ key + ','; 389 | } 390 | fakeROW = fakeROW.replace(/,+$/, ""); 391 | return fakeROW; 392 | } 393 | 394 | function mysql_commasetclause(jsobj) 395 | { 396 | var stmt = ''; 397 | for (var key in jsobj) { 398 | var val = jsobj[key]; 399 | if(Object.prototype.toString.call(val) === '[object Date]') 400 | val = val.toISOString().replace('T',' '); 401 | if(val != null && !Number.isInteger(val)) 402 | val = '\''+ val+'\''; 403 | stmt += ' ' + key + ' = '+ val + ','; 404 | } 405 | stmt = stmt.replace(/,+$/, ""); 406 | return stmt; 407 | } 408 | 409 | function mysql_commakeylist(jsobj) 410 | { 411 | var stmt = ''; 412 | for (var key in jsobj) { 413 | 414 | stmt += ' ' + key + ','; 415 | } 416 | stmt = stmt.replace(/,+$/, ""); 417 | return stmt; 418 | } 419 | 420 | function mysql_commavallist(jsobj) 421 | { 422 | var stmt = ''; 423 | for (var key in jsobj) { 424 | var val = jsobj[key]; 425 | if(Object.prototype.toString.call(val) === '[object Date]') 426 | val = val.toISOString(); 427 | if(Object.prototype.toString.call(val) === '[object String]' ){ 428 | if(val.endsWith('.000Z')){ 429 | // most likely a date, but still in String format, we'll format as a mysql timestamp 430 | // we might need to get the mysql column type with SHOW columns from table... 431 | if(Date.parse(val) != NaN) 432 | val = new Date(val).toJSON().slice(0, 19).replace('T', ' '); 433 | } 434 | } 435 | if(val != null && !Number.isInteger(val)) 436 | val = '\''+ val+'\''; 437 | stmt += ' ' + val + ','; 438 | } 439 | stmt = stmt.replace(/,+$/, ""); 440 | return stmt; 441 | } 442 | 443 | function mysql_andclause(jsobj) 444 | { 445 | var stmt = ''; 446 | for (var key in jsobj) { 447 | var val = jsobj[key]; 448 | if(Object.prototype.toString.call(val) === '[object Date]') 449 | val = val.toISOString(); 450 | if(Object.prototype.toString.call(val) === '[object String]' ){ 451 | if(val.endsWith('.000Z')){ 452 | // most likely a date, but still in String format, we'll format as a mysql timestamp 453 | // we might need to get the mysql column type with SHOW columns from table... 454 | if(Date.parse(val) != NaN) 455 | val = new Date(val).toJSON().slice(0, 19).replace('T',' '); 456 | }if(val.match(/^\d\d\d\d-\d\d-\d\dT\d\d:\d\d:\d\d$/,) != null) 457 | val = val.replace('T',' '); 458 | 459 | } 460 | if(val != null && !Number.isInteger(val)) 461 | val = '\''+ val+'\''; 462 | if(val == null) 463 | stmt += ' ' + key + ' is '+ val + ' AND'; 464 | else 465 | stmt += ' ' + key + ' = '+ val + ' AND'; 466 | } 467 | stmt = stmt.replace(/AND$/, ""); 468 | return stmt; 469 | } 470 | 471 | function pg_declaretriggervars(proc,timing,action,tableName) 472 | { 473 | var tgargs = proc.action_statement.split('(')[1].split(')')[0]; 474 | //console.log('args:'+tgargs); 475 | var tgargsarr = tgargs.split(','); 476 | //console.log(tgargsarr); 477 | if(tgargsarr[0] =='') 478 | tgargsarr = []; 479 | 480 | var decl = ` 481 | TG_NAME name DEFAULT '`+proc.trigger_name+`'; 482 | TG_WHEN text DEFAULT '`+timing.toUpperCase()+`'; 483 | TG_LEVEL text DEFAULT 'ROW'; 484 | TG_OP text DEFAULT '`+action.toUpperCase()+`'; 485 | TG_RELNAME name DEFAULT '`+tableName+`'; 486 | TG_TABLE_NAME name DEFAULT '`+tableName+`'; 487 | TG_TABLE_SCHEMA name DEFAULT '`+proc.foreignschema +`'; 488 | TG_NARGS integer DEFAULT `+(tgargsarr.length)+`;\n`; 489 | if(tgargsarr.length > 1) 490 | decl += `TG_ARGV TEXT[] DEFAULT ARRAY[`+proc.action_statement.split('(')[1].split(')')[0]+`];\n`; 491 | else 492 | decl += `TG_ARGV TEXT[] DEFAULT ARRAY[]::TEXT[];\n`; 493 | return decl; 494 | } 495 | 496 | function createtriggerwrap(procs,timing,action,tableName) 497 | { 498 | const rndid = Math.floor(Math.random() * 100000000); 499 | var procname = 'mysqltrig'+timing.toLowerCase()+rndid; 500 | // TODO ADD other trigger params 501 | var customprosrc = `create function pg_temp.`+procname+`(`; 502 | if(action == 'INSERT') 503 | customprosrc += `NEW RECORD`; 504 | else if(action == 'UPDATE') 505 | customprosrc += `OLD RECORD, NEW RECORD`; 506 | else if(action == 'DELETE') 507 | customprosrc += `OLD RECORD`; 508 | customprosrc += `) returns `; 509 | customprosrc += ` jsonb \n`; 510 | customprosrc += `AS $$ 511 | DECLARE 512 | BEGIN 513 | 514 | -- body of each trigger in order 515 | `; 516 | // we are executing all before triggers first to see if triggers affect NEW 517 | var triggercount = 0; 518 | for (var i = procs.length - 1; i >= 0; i--) { 519 | if(procs[i].action_timing.toUpperCase() == timing.toUpperCase()){ 520 | triggercount +=1; 521 | 522 | // https://www.postgresql.org/docs/11/plpgsql-trigger.html we need to 523 | // replace return X by (NEW|OLD) = X; and detect if X is null in which case we stop concat triggers, and set a flag to revert this operation silently (delete if insert) (undelete) etc 524 | //regexp_replace(procsr, '([\\\s|;])RETURN(\\\s)+[^;]+;', '\\1', 'ig') 525 | var retvar; 526 | if(action == 'INSERT' || action == 'UPDATE'){ 527 | retvar = 'NEW'; 528 | //procs[i].prosrc = procs[i].prosrc.replace(/RETURN\s+([^;]+);/ig,'NEW = $1;'); 529 | }else 530 | { 531 | retvar = 'OLD'; 532 | //procs[i].prosrc = procs[i].prosrc.replace(/RETURN\s+([^;]+);/ig,'OLD = $1;'); 533 | } 534 | 535 | // replace return statement by NEW = NEW or OLD = OLD 536 | procs[i].prosrc = procs[i].prosrc.replace(/RETURN\s+([^;]+);/ig,retvar + ' = $1;'); 537 | 538 | var splitonfirstbegin = procs[i].prosrc.split(/BEGIN([\s|\t|\n|.]+)/ig); 539 | //console.log(JSON.stringify(splitonfirstbegin)); 540 | var splitfirstbeginlen = splitonfirstbegin.length-1; 541 | // replace END; $$ by END IF; EBD; $$ 542 | splitonfirstbegin[splitfirstbeginlen] = splitonfirstbegin[splitfirstbeginlen].substring(0, splitonfirstbegin[splitfirstbeginlen].toUpperCase().lastIndexOf('END')) +'\nEND IF;\n END;\n'; 543 | 544 | // insert trigger args and an if clause to not execute if return wasn NULLed 545 | procs[i].prosrc = splitonfirstbegin[0].replace(/DECLARE[\s|\n]*/ig, `DECLARE \n`+ pg_declaretriggervars(procs[i],timing.toUpperCase(),action.toUpperCase(),tableName) ) + `\nBEGIN\n IF NOT(`+retvar+` is NULL) THEN\n\n` + splitonfirstbegin[splitfirstbeginlen] ; 546 | 547 | customprosrc += procs[i].prosrc; 548 | } 549 | } 550 | if(action == 'INSERT' || action == 'UPDATE') 551 | customprosrc += `return row_to_json(NEW);\n`; 552 | else if( action == 'DELETE') 553 | customprosrc += `return row_to_json(OLD);\n`; 554 | customprosrc += `END; 555 | $$ LANGUAGE plpgsql; 556 | `; 557 | //console.log(customprosrc); 558 | return {'procname':procname,'triggercount':triggercount,'customprosrc':customprosrc}; 559 | } 560 | 561 | const delay = ms => new Promise(res => setTimeout(res, ms)); 562 | var local_generatedupdates= {}; 563 | var pending_updates={}; 564 | var pending_change_updates={}; 565 | var pg_deletes= {}; 566 | 567 | 568 | 569 | 570 | 571 | zongji.on('binlog', function(evt) { 572 | 573 | console.log("+++++++++ :: " + evt.getTypeName() ); 574 | if(evt.getTypeName() === 'UpdateRows'){ 575 | 576 | // prob need to lock on table name here for ops to be in order 577 | 578 | 579 | // we unfortunately have to lock out other updates to the same table to ensure updates occur in order because we are potentially altering rows in before triggers 580 | lock.acquire(evt.tableMap[evt.tableId].tableName, async function() { 581 | const pgclient = await pgpool.connect() 582 | 583 | 584 | //var pgsql_storedProcs = pgsql_storedProcsQuery(evt,'UPDATE'); 585 | //console.log("pgsql_storedProcs query:"+pgsql_storedProcs); 586 | //const res = await pgclient.query(pgsql_storedProcs); 587 | const res = await pgsql_storedProcsAsync(pgclient,evt,'UPDATE'); 588 | //console.log(res.rows[0]); 589 | if(res.procs){ 590 | // so we have at least one ON UPDATE stored proc in pg for this table 591 | var procs = res.procs; 592 | //console.log(procs); 593 | 594 | // these are the corresponding pg foreignschemas 595 | var foreignschemas = res.foreignschemas[0]; 596 | // for (var i = foreignschemas.length - 1; i >= 0; i--) { 597 | // foreignschemas[procs[i].foreignschema] = procs[i].foreignschema; 598 | // } 599 | const foreignschemasarr = Object.keys(foreignschemas); 600 | 601 | // let's check if we have our special row 602 | if(!("pgrti" in evt.rows[0].before)) 603 | { 604 | //console.log("about to add pgrti"); 605 | // this is the first time we see this table, we need to add our sentinel col 606 | await addpgrti(evt.rows[0].before,foreignschemasarr,evt.tableMap[evt.tableId].tableName,pgclient); 607 | }else{ 608 | 609 | // check if the pgrti triggers are still there, if the foreign schema was dropped we need to recreate 610 | if(res.pgrti == false) 611 | await addpgrti(evt.rows[0].before,foreignschemasarr,evt.tableMap[evt.tableId].tableName,pgclient,true); 612 | //console.log('local_generatedupdates:'+ JSON.stringify(local_generatedupdates)); 613 | // if this evt occured before we had a pgrti col, or does not know about pgrti (mysql client) or did not change the pgrti (mysql) execute trigger procs's code 614 | if( //( !("pgrti" in evt.rows[0].before) || 615 | //(evt.rows[0].before.pgrti == null && typeof(local_generatedupdates[evt.rows[0].after.pgrti]) == 'undefined') || 616 | 617 | // negative list here for clarity 618 | !( 619 | // define events to be ignored: mysql originating events implies before == after for pgrti, if it's not the case we ignore 620 | evt.rows[0].before.pgrti != evt.rows[0].after.pgrti 621 | //) 622 | || 623 | // we specifically ignore some events, set to 42 when we want to ignore first op in addpgrti, -42424242 for pre del updates, and local_generatedupdates contains local edits or reverses as keys 624 | typeof(local_generatedupdates[evt.rows[0].after.pgrti]) != 'undefined' || 625 | evt.rows[0].after.pgrti == -42424242 626 | ) 627 | ) 628 | { 629 | 630 | //detected a change comming from mysql fire postgres triggers 631 | console.log("---FIRE POSTGRES UPDATE TRIGGERS:" + evt.getTypeName() + ' ON ' + evt.tableMap[evt.tableId].tableName ); 632 | //console.log("BEFORE:" + JSON.stringify(evt.rows[0].before) ); 633 | //console.log("AFTER:" + JSON.stringify(evt.rows[0].after) ); 634 | 635 | 636 | var beforeproc = createtriggerwrap(procs,'BEFORE','UPDATE',evt.tableMap[evt.tableId].tableName); 637 | var afterproc = createtriggerwrap(procs,'AFTER','UPDATE',evt.tableMap[evt.tableId].tableName); 638 | 639 | 640 | var beforetrigger_res; 641 | if(beforeproc.triggercount > 0 ) 642 | { 643 | //var ignorerti = []; 644 | for (var i = evt.rows.length - 1; i >= 0; i--) { 645 | 646 | // lets check if a change is pending 647 | //console.log('pending_updates:'+ JSON.stringify(pending_updates,null,4)); 648 | //console.log('evt.rows[i].before:'+ JSON.stringify(evt.rows[i].before)); 649 | //console.log('evt.rows[i].after:'+ JSON.stringify(evt.rows[i].after)); 650 | 651 | if(pending_updates[JSON.stringify(evt.rows[i].before)]){ 652 | console.log('-------MERGING'); 653 | 654 | var pending = pending_updates[JSON.stringify(evt.rows[i].before)]; 655 | //delete pending_updates[JSON.stringify(evt.rows[i].before)]; 656 | // we need to recurse there might several updates pending 657 | // while(pending_updates[JSON.stringify(pending)]) 658 | // pending = pending_updates[JSON.stringify(evt.rows[i].before)]; 659 | 660 | var fakeOLD = pgsql_fakeREC(pending,foreignschemas[foreignschemasarr[0]]); 661 | // BUGFIX: WE NEED TO ATTEMPT MERGE OF FAKE NEW HERE, prevent key override 662 | var merge = JSON.parse(JSON.stringify(pending)); 663 | for (var j = Object.keys(evt.rows[i].before).length - 1; j >= 0; j--) { 664 | var key = Object.keys(evt.rows[i].before)[j]; 665 | // apply only the keys that have been modified to our synthetic NEW 666 | if(evt.rows[i].before[key] != evt.rows[i].after[key]) 667 | merge[key] = evt.rows[i].after[key]; 668 | } 669 | //currdbstate = JSON.stringify(evt.rows[i].after); 670 | //console.log('--------------currdbstate:'+currdbstate); 671 | // HACKATTACK 672 | pending_updates[JSON.stringify(evt.rows[i].before)] = evt.rows[i].after; 673 | evt.rows[i].after = pending; 674 | //console.log('-------MERGING:after'+JSON.stringify(evt.rows[i].before)); 675 | 676 | var fakeNEW = pgsql_fakeREC(merge,foreignschemas[foreignschemasarr[0]]); 677 | // we need to add a pending from our before too 678 | // console.log('-------ADDING:'+JSON.stringify(pending)+" with: "+JSON.stringify(merge)); 679 | // pending_updates[JSON.stringify(pending)] = merge; 680 | // setTimeout(function(){ 681 | // delete pending_updates[JSON.stringify(pending)]; 682 | // }, 1000); 683 | 684 | // we dont know in what state we'll find the db so we add both 685 | //console.log('pending_updates:'+ JSON.stringify(pending_updates,null,4)); 686 | } 687 | else{ 688 | var fakeOLD = pgsql_fakeREC(evt.rows[i].before,foreignschemas[foreignschemasarr[0]]); 689 | var fakeNEW = pgsql_fakeREC(evt.rows[i].after,foreignschemas[foreignschemasarr[0]]); 690 | } 691 | //console.log('-------FAKEOLD:'+ fakeOLD); 692 | //console.log('-------fakeNEW:'+ fakeNEW); 693 | beforeproc.customprosrc += `select pg_temp.`+beforeproc.procname+`(old,new) from (`+fakeOLD+`) as old,(`+fakeNEW+`) as new;`; 694 | } 695 | //console.log('beforeproc.customprosrc:'+beforeproc.customprosrc); 696 | beforetrigger_res =await pgclient.query(beforeproc.customprosrc); 697 | //console.log('beforetrigger_res'+JSON.stringify(beforetrigger_res)); 698 | 699 | 700 | var updtstmt = ''; 701 | for (var i = evt.rows.length - 1; i >= 0; i--) { 702 | // beforetrigger_res is offset by 1 because the first row of the res is for the creation of our wrapper function 703 | var postbeforetrigger_row=beforetrigger_res[i+1].rows[0][beforeproc.procname]; 704 | //console.log('postbeforetrigger_row'+JSON.stringify(postbeforetrigger_row)); 705 | if(postbeforetrigger_row == null) 706 | { 707 | console.log('BEFORE UPDATE TRIGGER evt row:'+i+ ' returned NULL we silently undo the UPDATE!:'+JSON.stringify(evt.rows[i])); 708 | 709 | // BUG HERE TO FIX: WE NEED TO CHECK IF WE HAVE A PENDING REVERT ON THIS EDIT: THE PROBLEM IS THE RANDOM PGRTI MESSSes things up. probably removing the pgrti from the pending_updates hash would fix it 710 | 711 | //console.log('pending_updates:'+ JSON.stringify(pending_updates)); 712 | //console.log('evt.rows[i].before:'+ JSON.stringify(evt.rows[i].before)); 713 | //console.log('evt.rows[i].after:'+ JSON.stringify(evt.rows[i].after)); 714 | 715 | 716 | 717 | // lets check if this update is actually awaiting a revert that has not occured yet 718 | if(pending_updates[JSON.stringify(evt.rows[i].before)] ) 719 | { 720 | var orig = pending_updates[JSON.stringify(evt.rows[i].before)]; 721 | // to silently UPDATE row, we pgrti to a new value, as if this update came from postgres 722 | orig.pgrti = Math.floor(Math.random() * 100000000); 723 | var setrowclause = mysql_commasetclause(orig); 724 | // we remove pgrti from where clause to make sure the concurrent op does not prevent the change; could it occur after our revert? 725 | var afterminuspgrti = JSON.parse(JSON.stringify(evt.rows[i].after)); 726 | delete afterminuspgrti.pgrti; 727 | var whererowclause = mysql_andclause(afterminuspgrti); 728 | pending_updates[JSON.stringify(evt.rows[i].after)] = orig; 729 | updtstmt += 'UPDATE '+evt.tableMap[evt.tableId].tableName+' SET '+setrowclause+' WHERE ' + whererowclause + ';'; 730 | }else 731 | { 732 | 733 | 734 | // to silently UPDATE row, we pgrti to a new value, as if this update came from postgres 735 | evt.rows[i].before.pgrti = Math.floor(Math.random() * 100000000); 736 | local_generatedupdates[evt.rows[i].before.pgrti] = evt.rows[i].before.pgrti; 737 | var setrowclause = mysql_commasetclause(evt.rows[i].before); 738 | 739 | // we remove pgrti from where clause to make sure the concurrent op does not prevent the change; could it occur after our revert? 740 | var afterminuspgrti = JSON.parse(JSON.stringify(evt.rows[i].after)); 741 | delete afterminuspgrti.pgrti; 742 | var whererowclause = mysql_andclause(afterminuspgrti); 743 | pending_updates[JSON.stringify(evt.rows[i].after)] = evt.rows[i].before; 744 | // this mysql revert will not fire the trigger because we are updating pgrti 745 | updtstmt += 'UPDATE '+evt.tableMap[evt.tableId].tableName+' SET '+setrowclause+' WHERE ' + whererowclause + ';'; 746 | } 747 | 748 | 749 | 750 | 751 | }else{ 752 | 753 | var change = subtract(postbeforetrigger_row, evt.rows[i].after); 754 | 755 | // update silently mysql if NEW was modified by triggers 756 | if(Object.keys(change).length > 0) 757 | { 758 | 759 | //console.log('BEFORE TRIGGER evt row:'+i+ ' caused a change:'+JSON.stringify(change)); 760 | console.log('GENERATING MYSQL SILENT UPDATE: for it to be silent we are resetting pgrti so the update triggers will not be fired'); 761 | 762 | change.pgrti = Math.floor(Math.random() * 100000000); 763 | // WHY WOULD WE NEED THIS HERE? BY CHANGING THE VALUE WE AVERT THE PRESENT TRIGGER 764 | // WE NEED THIS TO PREVENT CIRCULAR UPDATES!!!! 765 | local_generatedupdates[change.pgrti] = change.pgrti; 766 | // 767 | //local_generatedupdates[JSON.stringify(evt.rows[i].after)] = JSON.stringify(change); 768 | var setrowclause = mysql_commasetclause(change); 769 | //console.log('setrowclause;'+setrowclause); 770 | // should we we remove pgrti from where clause to make sure the concurrent op does not prevent the change; could it occur after our revert? 771 | var afterminuspgrti = JSON.parse(JSON.stringify(evt.rows[i].after)); 772 | delete afterminuspgrti.pgrti; 773 | var whererowclause = mysql_andclause(afterminuspgrti); 774 | //var whererowclause = mysql_andclause(evt.rows[i].after); 775 | 776 | 777 | //console.log('whererowclause;'+whererowclause); 778 | 779 | updtstmt += 'UPDATE '+evt.tableMap[evt.tableId].tableName+' SET '+setrowclause+' WHERE ' + whererowclause + ';'; 780 | //console.log('AFTER'+JSON.stringify(evt.rows[i].after)); 781 | var row = evt.rows[i].after; 782 | var pendingchangeJSON = JSON.stringify(evt.rows[i].after); 783 | //update our after row with the trigger mods 784 | for (var j = Object.keys(change).length - 1; j >= 0; j--) { 785 | var key = Object.keys(change)[j]; 786 | if(key != 'pgrti') 787 | row[key] = change[key]; 788 | } 789 | pending_updates[pendingchangeJSON] = row; 790 | setTimeout(function(){ 791 | delete pending_updates[pendingchangeJSON]; 792 | }, 1000); 793 | 794 | if(pending_updates[JSON.stringify(evt.rows[i].before)]) 795 | { 796 | //console.log('HACKATTACK'); 797 | 798 | var currdbstate = JSON.stringify(pending_updates[JSON.stringify(evt.rows[i].before)]); 799 | delete pending_updates[JSON.stringify(evt.rows[i].before)]; 800 | // we did a merge, we'll also add that state 801 | pending_updates[currdbstate] = row; 802 | setTimeout(function(){ 803 | delete pending_updates[currdbstate]; 804 | }, 1000); 805 | } 806 | 807 | 808 | 809 | 810 | //console.log('++++++++++++++++++++pending_updates:'+ JSON.stringify(pending_updates,null,4)); 811 | 812 | 813 | 814 | } 815 | } 816 | } 817 | console.log(updtstmt); 818 | // update all rows that changed at once for efficiency 819 | mysqlpool.query(updtstmt); 820 | 821 | } 822 | 823 | 824 | // run AFTER triggers with updated row if we have after triggers 825 | if(afterproc.triggercount > 0) 826 | { 827 | for (var i = evt.rows.length - 1; i >= 0; i--) { 828 | 829 | // if we had beforetriggers, we only run aftertriggers if the result of before triggers is not null 830 | if(beforeproc.triggercount == 0 || beforetrigger_res[i-1] != null) 831 | { 832 | var fakeNEW = pgsql_fakeREC(evt.rows[i].after,foreignschemas[foreignschemasarr[0]]); 833 | var fakeOLD = pgsql_fakeREC(evt.rows[i].before,foreignschemas[foreignschemasarr[0]]); 834 | afterproc.customprosrc += `select pg_temp.`+afterproc.procname+`(old,new) from (`+fakeOLD+`) as old,(`+fakeNEW+`) as new;`; 835 | //console.log('afterproc.customprosrc:::: '+afterproc.customprosrc ); 836 | //console.log('foreignschemas[foreignschemasarr[0]]:::: '+JSON.stringify(foreignschemas[foreignschemasarr[0]]) ); 837 | } 838 | } 839 | //console.log(afterproc.customprosrc); 840 | const afterres =await pgclient.query(afterproc.customprosrc); 841 | } 842 | 843 | }else 844 | { 845 | 846 | // based on pgrti this event came from pg remove these markers so next time we see these from mysql the event is fired 847 | for (var i = evt.rows.length - 1; i >= 0; i--) { 848 | delete local_generatedupdates[evt.rows[i].after.pgrti]; 849 | } 850 | 851 | } 852 | 853 | 854 | } 855 | 856 | }//if(res.row.len) 857 | 858 | pgclient.release() 859 | }); 860 | // this is required to end an anonymous async function like this ;(async function() { 861 | //() 862 | 863 | 864 | // remove if was listed as pending. we do this as late as possible to allow a update-delete to be reverted to original, there's a chance this may not work 100% of the time... 865 | setTimeout(function(){ 866 | for (var i = evt.rows.length - 1; i >= 0; i--) 867 | delete pending_updates[JSON.stringify(evt.rows[i].after)]; 868 | }, 1000); 869 | 870 | 871 | 872 | // POSSIBLE IMPROVEMENT could we add a catch up system to write the binlog offset in our pgrti, so that if events occured while pg was offline the triggers get processed when it comes back online 873 | // we could encode the offset in pgrti by making that a bigint and kee the random bellow a certain limit; when the pg trigger fails we'll write the binlog offset+to pgrti (new op), then when pg is back (first lookup for triggers that succeeds) 874 | // we fire and update all pent up triggers and update the pgrtis 875 | //evt.dump(); 876 | 877 | 878 | }else if(evt.getTypeName() === 'WriteRows'){ // INSERT 879 | 880 | //console.log(JSON.stringify(evt.rows[0])); 881 | // anonymous asnyc fctn defined and called at once 882 | ;(async function() { 883 | const pgclient = await pgpool.connect() 884 | 885 | //var pgsql_storedProcs = pgsql_storedProcsQuery(evt,'INSERT'); 886 | //console.log('pgsql_storedProcs:'+pgsql_storedProcs); 887 | //const res = await pgclient.query(pgsql_storedProcs); 888 | const res = await pgsql_storedProcsAsync(pgclient,evt,'INSERT'); 889 | //console.log('pgsql_storedProcs:'+JSON.stringify(res)); 890 | if(res.procs){ 891 | 892 | 893 | var procs = res.procs; 894 | 895 | // these are the corresponding pg foreignschemas 896 | var foreignschemas = res.foreignschemas[0]; 897 | // for (var i = foreignschemas.length - 1; i >= 0; i--) { 898 | // foreignschemas[procs[i].foreignschema] = procs[i].foreignschema; 899 | // } 900 | const foreignschemasarr = Object.keys(foreignschemas); 901 | 902 | if(!("pgrti" in evt.rows[0])) 903 | { 904 | await addpgrti(evt.rows[0],foreignschemasarr,evt.tableMap[evt.tableId].tableName,pgclient); 905 | }else{ 906 | //console.log(procs); 907 | 908 | // check if the pgrti triggers are still there, if the foreign schema was dropped we need to recreate 909 | if(res.pgrti == false) 910 | await addpgrti(evt.rows[0].before,foreignschemasarr,evt.tableMap[evt.tableId].tableName,pgclient,true); 911 | 912 | if( !("pgrti" in evt.rows[0]) || evt.rows[0].pgrti < 0 ) 913 | { 914 | // this event has come from the mysqld 915 | 916 | // SMALL BUG: IF THE FIRST OPERATION came from postgres the trigger will be fired twice 917 | console.log("FIRE POSTGRES INSERT TRIGGERS:" + evt.getTypeName() + ' ON ' + evt.tableMap[evt.tableId].tableName); 918 | 919 | var beforeproc = createtriggerwrap(procs,'BEFORE','INSERT',evt.tableMap[evt.tableId].tableName); 920 | var afterproc = createtriggerwrap(procs,'AFTER','INSERT',evt.tableMap[evt.tableId].tableName); 921 | 922 | 923 | var beforetrigger_res; 924 | if(beforeproc.triggercount > 0 ) 925 | { 926 | for (var i = evt.rows.length - 1; i >= 0; i--) { 927 | // all foreignschemas should be the same for this table otherwire ops would fail 928 | var fakeNEW = pgsql_fakeREC(evt.rows[i],foreignschemas[foreignschemasarr[0]]); 929 | beforeproc.customprosrc += `select pg_temp.`+beforeproc.procname+`(evtro) from (`+fakeNEW+`) as evtro;`; 930 | } 931 | //console.log('beforeproc.customprosrc\n'+beforeproc.customprosrc); 932 | beforetrigger_res =await pgclient.query(beforeproc.customprosrc); 933 | //console.log(beforetrigger_res); 934 | var updtstmt = ''; 935 | for (var i = evt.rows.length - 1; i >= 0; i--) { 936 | //console.log(beforetrigger_res[i+1].rows[0]); 937 | // beforetrigger_res[i+1] is offset by one because the first res if from the creation of our composed before trigger 938 | var postbeforetrigger_row=beforetrigger_res[i+1].rows[0][beforeproc.procname]; 939 | 940 | console.log(postbeforetrigger_row); 941 | if(postbeforetrigger_row == null) 942 | { 943 | console.log('BEFORE TRIGGER evt row:'+i+ ' returned NULL we silently undo the insert!:'+JSON.stringify(evt.rows[i])); 944 | // to silently delete row, we first need to first silently set pgrti to our sentinel -42424242 945 | // this will not fire the trigger because we are updating pgrti 946 | var setrowclause = mysql_commasetclause({pgrti:-42424242}); 947 | var whererowclause = mysql_andclause(evt.rows[i]); 948 | updtstmt += 'UPDATE '+evt.tableMap[evt.tableId].tableName+' SET '+setrowclause+' WHERE ' + whererowclause + ';'; 949 | // because of previous update to sentinel value this delete will also be silent and not fire the triggers 950 | evt.rows[i].pgrti = -42424242; 951 | whererowclause = mysql_andclause(evt.rows[i]); 952 | updtstmt += 'DELETE FROM '+evt.tableMap[evt.tableId].tableName+' WHERE ' + whererowclause + ';'; 953 | 954 | }else{ 955 | 956 | var change = subtract(postbeforetrigger_row, evt.rows[i]); 957 | console.log('BEFORE TRIGGER evt row:'+i+ ' caused change:'+JSON.stringify(change)); 958 | 959 | // update silently mysql if NEW was modified by triggers 960 | if(Object.keys(change).length > 0) 961 | { 962 | console.log('GENERATING MYSQL SILENT UPDATE: for it to be silent we are setting pgrti so the update triggers will not be fired'); 963 | change.pgrti = Math.floor(Math.random() * 100000000); 964 | local_generatedupdates[change.pgrti] = change.pgrti; 965 | var setrowclause = mysql_commasetclause(change); 966 | //console.log('setrowclause;'+setrowclause); 967 | 968 | var whererowclause = mysql_andclause(evt.rows[i]); 969 | //console.log('whererowclause;'+whererowclause); 970 | 971 | updtstmt += 'UPDATE '+evt.tableMap[evt.tableId].tableName+' SET '+setrowclause+' WHERE ' + whererowclause + ';'; 972 | 973 | var row = evt.rows[i]; 974 | //update our row with the trigger mods 975 | for (var i = Object.keys(change).length - 1; i >= 0; i--) { 976 | var key = Object.keys(change)[i]; 977 | if(key != 'pgrti') 978 | row[key] = change[key]; 979 | } 980 | evt.rows[i] = row; 981 | //console.log('updated row:'+JSON.stringify(evt.rows[i])); 982 | } 983 | } 984 | } 985 | //console.log(updtstmt); 986 | // update all rows that changed at once for efficiency 987 | if(updtstmt != '') 988 | mysqlpool.query(updtstmt); 989 | 990 | } 991 | 992 | 993 | 994 | // run AFTER triggers with updated row if we have after triggers 995 | if(afterproc.triggercount > 0) 996 | { 997 | for (var i = evt.rows.length - 1; i >= 0; i--) { 998 | // if we had before triggers, only run after trigger for rows that did not return null 999 | // if we only have after triggers we'll run them 1000 | if(beforeproc.triggercount == 0 || beforetrigger_res[i-1] != null) 1001 | { 1002 | var fakeNEW = pgsql_fakeREC(evt.rows[i],foreignschemas[foreignschemasarr[0]]); 1003 | afterproc.customprosrc += `select pg_temp.`+afterproc.procname+`(evtro) from (`+fakeNEW+`) as evtro;`; 1004 | } 1005 | } 1006 | //console.log(afterproc.customprosrc); 1007 | const afterres =await pgclient.query(afterproc.customprosrc); 1008 | } 1009 | } 1010 | } 1011 | }//if(res.rows.length > 0 && r 1012 | pgclient.release() 1013 | 1014 | })() 1015 | 1016 | } 1017 | else if(evt.getTypeName() === 'DeleteRows'){ 1018 | 1019 | ;(async function() { 1020 | const pgclient = await pgpool.connect() 1021 | 1022 | //var pgsql_storedProcs = pgsql_storedProcsQuery(evt,'DELETE'); 1023 | //console.log(pgsql_storedProcs); 1024 | //const res = await pgclient.query(pgsql_storedProcs); 1025 | const res = await pgsql_storedProcsAsync(pgclient, evt,'DELETE'); 1026 | 1027 | if(res.procs){ 1028 | var procs = res.procs; 1029 | //console.log(procs); 1030 | 1031 | // these are the corresponding pg foreignschemas 1032 | var foreignschemas = res.foreignschemas[0]; 1033 | // for (var i = foreignschemas.length - 1; i >= 0; i--) { 1034 | // foreignschemas[procs[i].foreignschema] = procs[i].foreignschema; 1035 | // } 1036 | const foreignschemasarr = Object.keys(foreignschemas); 1037 | 1038 | if(!("pgrti" in evt.rows[0])) 1039 | { 1040 | await addpgrti(evt.rows[0],foreignschemasarr,evt.tableMap[evt.tableId].tableName,pgclient); 1041 | }else{ 1042 | 1043 | // check if the pgrti triggers are still there, if the foreign schema was dropped we need to recreate 1044 | if(res.pgrti == false) 1045 | await addpgrti(evt.rows[0].before,foreignschemasarr,evt.tableMap[evt.tableId].tableName,pgclient,true); 1046 | 1047 | //console.log(JSON.stringify(evt.rows[0])); 1048 | //-42424242 is sentinel value that we set in a postgres before trigger (this one is ignored by the current system) to identify deletes coming from postgres 1049 | var rowkey = evt.tableMap[evt.tableId].tableName+evt.rows[0].pgrti; 1050 | //console.log('check:'+rowkey); 1051 | if(!("pgrti" in evt.rows[0]) || (evt.rows[0].pgrti != -42424242 && (pg_deletes[rowkey] == undefined) ) ) 1052 | { 1053 | console.log("FIRE POSTGRES DELETE TRIGGERS:" + evt.getTypeName() + ' ON ' + evt.tableMap[evt.tableId].tableName); 1054 | 1055 | var beforeproc = createtriggerwrap(procs,'BEFORE','DELETE',evt.tableMap[evt.tableId].tableName); 1056 | var afterproc = createtriggerwrap(procs,'AFTER','DELETE',evt.tableMap[evt.tableId].tableName); 1057 | 1058 | var beforetrigger_res; 1059 | if(beforeproc.triggercount > 0) 1060 | { 1061 | var inserertstmt = ''; 1062 | for (var i = evt.rows.length - 1; i >= 0; i--) { 1063 | var fakeOLD = pgsql_fakeREC(evt.rows[i],foreignschemas[foreignschemasarr[0]]); 1064 | beforeproc.customprosrc += `select pg_temp.`+beforeproc.procname+`(evtro) from (`+fakeOLD+`) as evtro;`; 1065 | } 1066 | //console.log(beforeproc.customprosrc); 1067 | beforetrigger_res =await pgclient.query(beforeproc.customprosrc); 1068 | 1069 | 1070 | for (var i = evt.rows.length - 1; i >= 0; i--) { 1071 | // before trig res offset by one because the first stmt is to create the temp trigger wrapper 1072 | var postbeforetrigger_row=beforetrigger_res[i+1].rows[0][beforeproc.procname]; 1073 | 1074 | console.log(postbeforetrigger_row); 1075 | if(postbeforetrigger_row == null) 1076 | { 1077 | console.log('BEFORE TRIGGER evt row:'+i+ ' returned NULL we silently undo the DELETE!:'+JSON.stringify(evt.rows[i])); 1078 | // to silently re-insert row, we need to set pgrti 1079 | // this will not fire the trigger because we are updating pgrti 1080 | 1081 | //console.log('pending_updates:'+ JSON.stringify(pending_updates)); 1082 | if(pending_updates[JSON.stringify(evt.rows[i])] ) 1083 | { 1084 | // we have a pending revert, we insert that instead! 1085 | evt.rows[i] = pending_updates[JSON.stringify(evt.rows[i])]; 1086 | delete pending_updates[JSON.stringify(evt.rows[i])]; 1087 | } 1088 | 1089 | evt.rows[i].pgrti = Math.floor(Math.random() * 100000000); 1090 | inserertstmt += 'INSERT INTO '+evt.tableMap[evt.tableId].tableName+' ('+mysql_commakeylist(evt.rows[i]) +') '+' VALUES (' + mysql_commavallist(evt.rows[i]) + ');'; 1091 | } 1092 | } 1093 | if(inserertstmt != '') 1094 | mysqlpool.query(inserertstmt); 1095 | 1096 | 1097 | } 1098 | 1099 | if(afterproc.triggercount > 0) 1100 | { 1101 | for (var i = evt.rows.length - 1; i >= 0; i--) { 1102 | // after triggers are canceled if a before trigger returned NULL 1103 | if(beforeproc.triggercount == 0 || beforetrigger_res[i-1] != null) 1104 | { 1105 | var fakeOLD = pgsql_fakeREC(evt.rows[i],foreignschemas[foreignschemasarr[0]]); 1106 | afterproc.customprosrc += `select pg_temp.`+afterproc.procname+`(evtro) from (`+fakeOLD+`) as evtro;`; 1107 | } 1108 | } 1109 | //console.log(afterproc.customprosrc); 1110 | const afterres =await pgclient.query(afterproc.customprosrc); 1111 | } 1112 | } 1113 | } 1114 | }//if(res.rows.length > 0 && 1115 | pgclient.release() 1116 | 1117 | })() 1118 | } 1119 | }); 1120 | 1121 | 1122 | zongji.on('ready', function(evt) { 1123 | console.log('ready'); 1124 | 1125 | }); 1126 | 1127 | console.log("about to start rosettable on: "+ mysqlconfig.database); 1128 | 1129 | //'mqltestdb': true 1130 | includedschema = {} 1131 | includedschema[mysqlconfig.database] = true; 1132 | 1133 | 1134 | 1135 | 1136 | 1137 | const delNotifyClient = new pg.Client(pgconfig); 1138 | delNotifyClient.connect(err => { 1139 | if (err) { 1140 | console.error('connection error', err.stack) 1141 | } 1142 | 1143 | console.log('connected to:' + pgconfig.database) 1144 | 1145 | // Listen for all pg_notify channel messages 1146 | delNotifyClient.on('notification', function(msg) { 1147 | if(msg.channel == 'pg_silent_del') 1148 | { 1149 | console.log(JSON.stringify(msg)); 1150 | if(msg.payload) 1151 | { 1152 | let payload = JSON.parse(msg.payload); 1153 | //console.log('Flagging THIS delete as comming from pg.'); 1154 | 1155 | var rowkey = payload.tablename+payload.pgrti; 1156 | //console.log('rowkey'+rowkey); 1157 | pg_deletes[rowkey] = payload.pgrti; 1158 | setTimeout(function(){ 1159 | delete pg_deletes[rowkey]; 1160 | }, 1000); 1161 | } 1162 | 1163 | 1164 | 1165 | 1166 | } 1167 | 1168 | }); 1169 | 1170 | // Designate which channels we are listening on. Add additional channels with multiple lines. 1171 | delNotifyClient.query('LISTEN pg_silent_del'); 1172 | 1173 | }); 1174 | 1175 | zongji.start({ 1176 | //Unique number int32 >= 1 to identify this replication slave instance. Must be specified if running more than one instance of ZongJi. Must be used in start() method for effect. Default: 1 1177 | serverId : 1, 1178 | startAtEnd: true, 1179 | includeEvents: ['tablemap', 'writerows', 'updaterows', 'deleterows'], 1180 | includeSchema: includedschema 1181 | }); 1182 | 1183 | process.on('SIGINT', function() { 1184 | console.log('Got SIGINT.'); 1185 | zongji.stop(); 1186 | process.exit(); 1187 | }); -------------------------------------------------------------------------------- /runtests_mysql.sql: -------------------------------------------------------------------------------- 1 | #insert into mysql_mailtrain.employee values(default,'alice',2); 2 | 3 | USE mqltestdb; 4 | -- trigger wont be called if we are executing this test first 5 | update employee set emp_name = 'MYSQL_first_op' where emp_id = 2; 6 | -- OUR FIRST OP CAUSED THE PGRTI FIELD TO BE CREATED if we dont wait a few seconds all the operations will be queued before we're done adding the field 7 | select sleep(1); 8 | 9 | select 'check before update trigger' as '' ; 10 | update employee set emp_name = 'MYSQL2' where emp_id = 6; 11 | 12 | 13 | insert into employee(emp_id,emp_name,emp_dept_id) VALUES (DEFAULT, 'MYSQLINSERT--',2); 14 | 15 | 16 | -- test before delete revert while a revert might be pending update 17 | select 'check before delete trigger: we cannot delete id 4 (Postgres before trigger recreates silently in the next moment' as ''; 18 | delete from employee where emp_id = 4; 19 | delete from employee where emp_id = 4; 20 | delete from employee where emp_id = 4; 21 | delete from employee where emp_id = 4; 22 | 23 | 24 | select 'check before update trigger: we cannot update id 4 (Postgres before trigger reverts silently in the next moment' as '' ; 25 | update employee set emp_name = 'should revert' where emp_id = 4; 26 | -- do this again to see if we could get an out of order op like for update -> delete with both reverting befores 27 | select 'do this again to see if we could get an out of order op like for update -> delete with both reverting befores' as '' ; 28 | update employee set emp_name = 'should revert1' where emp_id = 4; 29 | update employee set emp_name = 'should revert2' where emp_id = 4; 30 | update employee set emp_name = 'should revert3' where emp_id = 4; 31 | 32 | 33 | select 'to address rapid updates with altering before triggers we needed to lock the on the table name, because of asyncness ops could occur in the wrong order' as '' ; 34 | update employee set emp_dept_id = 1 where emp_id = 5; 35 | update employee set emp_dept_id = 2 where emp_id = 5; 36 | update employee set emp_dept_id = 1 where emp_id = 5; 37 | -------------------------------------------------------------------------------- /runtests_pg.sql: -------------------------------------------------------------------------------- 1 | select 'RUNNING TESTS'; 2 | 3 | 4 | insert into fs_mqltestdb.employee values(default,'firsop_pg',2); 5 | select 'OUR FIRST OP CAUSED THE PGRTI FIELD TO BE CREATED if we dont wait a few seconds all the operations will be queued before we are done creating the structures'; 6 | select pg_sleep(3); 7 | 8 | select 'check that the before insert trigger runs only once'; 9 | insert into fs_mqltestdb.employee values(default,'runoncealice',2); 10 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 11 | 12 | 13 | 14 | 15 | select 'check before update trigger'; 16 | update fs_mqltestdb.employee set emp_name = 'pgupdate--' where emp_id = 3; 17 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 18 | 19 | select 'check before insert trigger: we cannot insert id 42'; 20 | insert into fs_mqltestdb.employee values(42,'PRESENCEWOULDBEABUGalice',2); 21 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 22 | 23 | select 'check before insert trigger: we can insert id 43'; 24 | insert into fs_mqltestdb.employee values(43,'alice',2); 25 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 26 | 27 | 28 | 29 | select 'check before update trigger: we cannot update id 4'; 30 | update fs_mqltestdb.employee set emp_name = 'should fail' where emp_id = 4; 31 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 32 | 33 | select 'check before delete trigger: we cannot delete id 4'; 34 | delete from fs_mqltestdb.employee where emp_id = 4; 35 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 36 | 37 | select 'test delete id 1'; 38 | delete from fs_mqltestdb.employee where emp_id = 1; 39 | select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee; 40 | 41 | -------------------------------------------------------------------------------- /sample.rosettable.conf: -------------------------------------------------------------------------------- 1 | { 2 | "comment_zongji":"this is the mysql connection and user the log watcher uses: it requires REPLICATION SLAVE, REPLICATION CLIENT, SELECT on the target database", 3 | "zongji_conf" : { 4 | "host" : "localhost", 5 | "user" : "pgtriggersd", 6 | "password" : "pointandshoot" 7 | }, 8 | 9 | 10 | "comment_pg":"this is the postgres connection and user rosettable uses to execute the triggers in postgres, adjust rights accordingly", 11 | "pgconfig" : { 12 | "user": "fdw_user", 13 | "password": "this_1s_fdw_us3r", 14 | "host": "localhost", 15 | "port": "5432", 16 | "database": "testdb_pg" 17 | }, 18 | 19 | "comment_mysql":"this is the mysql connection and user rosettable uses; potentially to revert operations after before triggers. it requires SELECT, UPDATE, INSERT, DELETE, ALTER on the target database", 20 | "mysqlconfig" : { 21 | "multipleStatements": true, 22 | "host" : "localhost", 23 | "user" : "pgtriggerscl", 24 | "password" : "pointandshoot2", 25 | "database": "mqltestdb", 26 | "waitForConnections": true, 27 | "connectionLimit": 10, 28 | "queueLimit": 0 29 | } 30 | } -------------------------------------------------------------------------------- /setupandtest.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | #run all unit tests on linux, you can do each steps individually on other OSes 4 | 5 | echo "setupandtest.sh with args: $*" 6 | echo "setupandtest.sh: we are assuming postgres and mysql are local, and that binlog has been enabled in my.cnf and mysql has been restarted" 7 | # origArgs=$* 8 | postgresport=5432 9 | if ! options=$(getopt -u -o r:d -l mysqlrootpass:,postgresport:,postgresuser:,postgrespass: -- "$@") 10 | then 11 | # something went wrong, getopt will put out an error message for us 12 | exit 1 13 | fi 14 | 15 | 16 | 17 | set -- $options 18 | 19 | while [ $# -gt 0 ] 20 | do 21 | case $1 in 22 | # for options with required arguments, an additional shift is required 23 | -r|--mysqlrootpass ) mysqlrootpass=$2; shift;; 24 | -p|--postgresport ) postgresport=$2; shift;; 25 | -U|--postgresuser ) postgresuser=$2; shift;; 26 | -P|--postgrespass ) postgrespass=$2; shift;; 27 | #-d|--ctScriptPath ) ctScriptPath=$2; shift;; 28 | 29 | #(-*) echo "$0: error - unrecognized option $1" 1>&2; exit 1;; 30 | (*) break;; 31 | esac 32 | shift 33 | done 34 | 35 | 36 | args="$*" 37 | # make sure our deamon is not running 38 | pkill -f 'node rosettable' 39 | while [ $? -eq 0 ]; do 40 | echo "deamon was running: wait for it to be dead" 41 | sleep 1; 42 | pkill -f 'node rosettable' 43 | done 44 | sleep 1; 45 | 46 | #ifnot download 47 | if [ -z "$mysqlrootpass" ]; then 48 | echo "the mysql root pass is required to create the test database"; 49 | exit 1; 50 | fi 51 | 52 | echo 'SETUP:creating our test database in mysql' 53 | mysqlargs="-u root -p$mysqlrootpass"; 54 | mysql $mysqlargs < setuptest_mysql_create_test_schema.sql 55 | 56 | 57 | echo 'SETUP:creating our test database in postgres, our test user, our mapping and some triggers' 58 | # this assumes we are running this script as root 59 | #su postgres -c "psql -p 5433 -f setuptest_pg_import_fdw_create_triggers.sql" 60 | #if that is not an option replace by where supuser has superuser rights 61 | PGPASSWORD=$postgrespass psql -h localhost -p $postgresport -U $postgresuser -f setuptest_pg_import_fdw_create_triggers.sql 62 | 63 | 64 | #start our binlog watching node process 65 | node rosettable.js > watcher1.log & triggerwatcherpid=$! 66 | echo "STARTED OUR WATCHING DEAMON: triggerwatcherpid: $triggerwatcherpid" 67 | # lets wait 2 seconds for it to be ready 68 | sleep 2 69 | 70 | echo 'run mysql test' 71 | mysql $mysqlargs < runtests_mysql.sql 72 | 73 | 74 | echo 'run pg tests' 75 | PGPASSWORD=this_1s_fdw_us3r psql -h localhost -p $postgresport -U fdw_user -d testdb_pg -f runtests_pg.sql > testres_mysql_then_pg.out 76 | 77 | if [ ! -f testexp_mysql_then_pg ]; then 78 | echo 'ERROR: missing testexp_mysql_then_pg cannot validate tests'; 79 | exit 1; 80 | fi 81 | testres=$(diff testres_mysql_then_pg.out testexp_mysql_then_pg ); 82 | if [ "$testres" != "" ]; then 83 | echo "AT LEAST ONE PG TEST FAIED!" 84 | sleep 1 85 | kill "$triggerwatcherpid" 86 | echo "$testres" 87 | exit 1; 88 | else 89 | echo "All mysql then pg tests succeded" 90 | fi 91 | 92 | echo "now run with first edit in PG" 93 | sleep 1 94 | kill "$triggerwatcherpid" 95 | sleep 2 96 | 97 | 98 | 99 | echo 'SETUP:creating our test database in mysql' 100 | mysqlargs="-u root -p$mysqlrootpass"; 101 | mysql $mysqlargs < setuptest_mysql_create_test_schema.sql 102 | 103 | 104 | echo 'SETUP:creating our test database in postgres, our test user, our mapping and some triggers' 105 | # this assumes we are running this script as root 106 | #su postgres -c "psql -p 5433 -f setuptest_pg_import_fdw_create_triggers.sql" 107 | #if that is not an option replace by where supuser has superuser rights 108 | PGPASSWORD=$postgrespass psql -h localhost -p $postgresport -U $postgresuser -f setuptest_pg_import_fdw_create_triggers.sql 109 | 110 | 111 | #start our binlog watching node process 112 | node rosettable.js > watcher2.log & triggerwatcherpid=$! 113 | echo "STARTED OUR WATCHING DEAMON: triggerwatcherpid: $triggerwatcherpid" 114 | # lets wait 2 seconds for it to be ready 115 | sleep 2 116 | 117 | echo 'run pg tests' 118 | PGPASSWORD=this_1s_fdw_us3r psql -h localhost -p $postgresport -U fdw_user -d testdb_pg -f runtests_pg.sql 119 | 120 | echo 'run mysql test' 121 | mysql $mysqlargs < runtests_mysql.sql 122 | 123 | PGPASSWORD=this_1s_fdw_us3r psql -h localhost -p $postgresport -U fdw_user -d testdb_pg -c 'select emp_id,emp_name,emp_dept_id,trigg_count from fs_mqltestdb.employee;' > testres_pg_then_mysql.out 124 | 125 | 126 | if [ ! -f testexp_pg_then_mysql ]; then 127 | echo 'ERROR: missing testexp_pg_then_mysql cannot validate tests'; 128 | exit 1; 129 | fi 130 | 131 | testres=$(diff testres_pg_then_mysql.out testexp_pg_then_mysql ); 132 | if [ "$testres" != "" ]; then 133 | echo "AT LEAST ONE PG TEST FAIED!" 134 | echo "$testres" 135 | sleep 1 136 | kill "$triggerwatcherpid" 137 | exit 1; 138 | else 139 | echo "All mysql then pg tests succeded" 140 | fi 141 | 142 | cat testres_pg_then_mysql.out 143 | 144 | echo "ALL TESTS PASSED" 145 | sleep 1 146 | kill "$triggerwatcherpid" 147 | 148 | -------------------------------------------------------------------------------- /setuptest_mysql_create_test_schema.sql: -------------------------------------------------------------------------------- 1 | 2 | -- this is the user our binlog watching deamon connects to mysql with; 3 | -- we are granting this role replication rights to all tables 4 | DROP USER IF EXISTS 'rosettableD'@'localhost'; 5 | CREATE USER 'rosettableD'@'localhost' IDENTIFIED BY 'pointandshoot'; 6 | GRANT REPLICATION SLAVE, REPLICATION CLIENT, SELECT ON *.* TO 'rosettableD'@'localhost'; 7 | FLUSH PRIVILEGES; 8 | 9 | -- this is the user that the process uses when it needs to alter the mysql schema to add a col and a trigger 10 | -- we are granting this role replication rights to all tables 11 | DROP USER IF EXISTS 'rosettableAdm'@'localhost'; 12 | CREATE USER 'rosettableAdm'@'localhost' IDENTIFIED BY 'admpasswatchout'; 13 | -- GRANT SELECT, UPDATE, INSERT, DELETE, ALTER ON *.* TO 'rosettableAdm'@'localhost'; 14 | GRANT SELECT,TRIGGER,SUPER, CREATE, UPDATE, INSERT, DELETE,LOCK TABLES, ALTER ON *.* TO 'rosettableAdm'@'localhost'; 15 | FLUSH PRIVILEGES; 16 | 17 | -- create a test database 18 | DROP DATABASE IF EXISTS mqltestdb; 19 | CREATE DATABASE mqltestdb; 20 | USE mqltestdb; 21 | 22 | -- this is our regular user that does the CRUD 23 | DROP USER IF EXISTS 'rosettableU'@'localhost'; 24 | CREATE USER 'rosettableU'@'localhost' IDENTIFIED BY 'pointandshoot2'; 25 | -- GRANT SELECT, UPDATE, INSERT, DELETE, ALTER ON *.* TO 'rosettableU'@'localhost'; 26 | GRANT SELECT, UPDATE, INSERT, DELETE ON mqltestdb.* TO 'rosettableU'@'localhost'; 27 | FLUSH PRIVILEGES; 28 | -- this role is used by our deamon to alter the schema to add a col on first use, and to revert changes when before triggers in pg would mandate 29 | 30 | 31 | -- our tables 32 | create table employee(emp_id int NOT NULL AUTO_INCREMENT PRIMARY KEY, emp_name text, emp_dept_id int, trigg_count int); 33 | -- populate with some fake data 34 | -- NB: this is the type of insert that will need a slight modification if presnt in other mysql clients: 35 | -- because this binlog watching trigger deamen adds a new col 36 | INSERT INTO employee VALUES(DEFAULT, 'emp - 1', 1,NULL); 37 | INSERT INTO employee VALUES(DEFAULT, 'emp - 2', 1,NULL); 38 | INSERT INTO employee VALUES(DEFAULT, 'emp - 3', 1,NULL); 39 | INSERT INTO employee VALUES(DEFAULT, 'emp - 4', 2,NULL); 40 | INSERT INTO employee VALUES(DEFAULT, 'emp - 5', 2,NULL); 41 | INSERT INTO employee VALUES(DEFAULT, 'emp - 6', 2,NULL); 42 | 43 | -- create a user for our postgres FDW. 44 | DROP USER IF EXISTS 'clientpg'@'localhost'; 45 | CREATE USER 'clientpg'@'localhost' IDENTIFIED BY 'fdwfordeworld'; 46 | GRANT ALL PRIVILEGES ON mqltestdb.* TO 'clientpg'@'localhost'; 47 | FLUSH PRIVILEGES; 48 | 49 | select 'ATTENTION for binlog watching to work you need to enable MySQL binlog in my.cnf (generally: /etc/mysql/my.cnf) and restart MySQL: see https://github.com/nevill/zongji' as ''; 50 | select 'Here is a sample:' as ''; 51 | select '[mysqld]' as ''; 52 | select '# Must be unique integer from 1-2^32' as ''; 53 | select 'server-id = 1' as ''; 54 | select '# Row format required for ZongJi' as ''; 55 | select 'binlog_format = row' as ''; 56 | select '# log directory must exist. This path works for Linux. Other OS may require a different path' as ''; 57 | select 'log_bin = /var/log/mysql/mysql-bin.log' as ''; 58 | select 'expire_logs_days = 10 # Optional, purge old logs' as ''; 59 | select 'max_binlog_size = 100M # Optional, limit log size' as ''; 60 | select 'binlog_do_db = mqltestdb # Optional?, limit which databases to log' as ''; -------------------------------------------------------------------------------- /setuptest_pg_import_fdw_create_triggers.sql: -------------------------------------------------------------------------------- 1 | -- this should run as a pg super user 2 | -- create one with 3 | --su - postgres 4 | --psql 5 | --CREATE ROLE rosettable LOGIN SUPERUSER PASSWORD '3passWorld'; 6 | --CREATE DATABASE rosettable; 7 | --GRANT ALL ON DATABASE rosettable to rosettable; 8 | 9 | select version(); 10 | DROP DATABASE testdb_pg; 11 | 12 | 13 | DROP USER IF EXISTS fdw_user; 14 | DROP USER IF EXISTS fdw_user2; 15 | -- this user is used both to own our mapping and by the deamon to list and run the triggers 16 | CREATE USER fdw_user WITH ENCRYPTED PASSWORD 'this_1s_fdw_us3r'; 17 | CREATE USER fdw_user2 WITH ENCRYPTED PASSWORD 'this_1s_fdw_us3r'; 18 | -- we need UTF8 19 | CREATE DATABASE testdb_pg WITH ENCODING 'UTF8' 20 | LC_COLLATE = 'en_US.UTF-8' 21 | LC_CTYPE = 'en_US.UTF-8' 22 | TEMPLATE template0 OWNER fdw_user; 23 | GRANT ALL ON DATABASE testdb_pg to fdw_user2; 24 | -- connect to our new DB 25 | \c testdb_pg; 26 | --SHOW SERVER_ENCODING; 27 | 28 | select 'ATTENTION !!! IF THIS MESSAGE STOPS YOUR TERMINAL WINDOW, REQUIRING YOU TO PRESS Q TO ~END, THE DIFF USED TO VERIFY THAT ALL TEST HAVE PASSED WILL ALWAYS FAIL RESIZE YOUR WINDOW!!!'; 29 | 30 | select 'ATTENTION this project requires a bugfix to the MYSQL_FDW that as of this writting has not been merged: you can get the fork here and compile:https://github.com/francoisp/mysql_fdw'; 31 | CREATE EXTENSION mysql_fdw; -- this needs to run as superuser, at this point we are still the user that started this script which should have all rights 32 | select mysql_fdw_version(); -- we did not update the official version yet, but when it is we should check we are running the version with the required fix 33 | 34 | -- we are assuming mysql and pg are on the same machine YMMV 35 | CREATE SERVER mysql_server FOREIGN DATA WRAPPER mysql_fdw OPTIONS (host '127.0.0.1', port '3306'); 36 | GRANT ALL PRIVILEGES ON FOREIGN SERVER mysql_server TO fdw_user; 37 | set role fdw_user; 38 | 39 | 40 | 41 | 42 | GRANT ALL PRIVILEGES ON DATABASE testdb_pg TO fdw_user; 43 | 44 | 45 | -- register our foreign data wrapper mapping, basically a serverside client connection 46 | CREATE USER MAPPING FOR fdw_user SERVER mysql_server OPTIONS (username 'clientpg', password 'fdwfordeworld'); 47 | select 'create a schema where we''ll map the foreign tables'; 48 | create schema fs_mqltestdb; 49 | 50 | -- this creates the mapping tables 51 | IMPORT FOREIGN SCHEMA mqltestdb FROM SERVER mysql_server INTO fs_mqltestdb; 52 | select 'we could have the same mysql db mapped at different locations, we need to support this'; 53 | create schema fs_mqltestdb2; 54 | IMPORT FOREIGN SCHEMA mqltestdb FROM SERVER mysql_server INTO fs_mqltestdb2; 55 | 56 | 57 | select 'create some test triggers and procedures'; 58 | CREATE OR REPLACE FUNCTION testinstrig() returns trigger 59 | AS $$ 60 | DECLARE 61 | BEGIN 62 | NEW.emp_name = NEW.emp_name || ' insert trigger mod!'; 63 | 64 | -- we will verify that the trigger is not fired twice 65 | IF NEW.trigg_count is NULL OR NEW.trigg_count = 0 THEN 66 | NEW.trigg_count = 1; 67 | ELSE 68 | NEW.trigg_count = NEW.trigg_count + 1; 69 | END IF; 70 | 71 | -- test revert with this 72 | IF NEW.emp_id = 42 THEN 73 | return NULL; 74 | END IF; 75 | 76 | return NEW; 77 | END; 78 | $$ LANGUAGE plpgsql; 79 | 80 | CREATE TRIGGER testinstrig BEFORE INSERT ON fs_mqltestdb.employee FOR EACH ROW EXECUTE PROCEDURE testinstrig(); 81 | 82 | CREATE OR REPLACE FUNCTION testuptrig() returns trigger 83 | AS $$ 84 | DECLARE 85 | BEGIN 86 | 87 | -- we will verify that the trigger is not fired twice 88 | IF NEW.trigg_count is NULL OR NEW.trigg_count = 0 THEN 89 | NEW.trigg_count = 1; 90 | ELSE 91 | NEW.trigg_count = NEW.trigg_count + 1; 92 | END IF; 93 | 94 | NEW.emp_name = NEW.emp_name || ' TRIGGER UPDATED!'; 95 | 96 | -- test revert with this 97 | IF NEW.emp_id = 4 THEN 98 | return NULL; 99 | END IF; 100 | 101 | return NEW; 102 | END; 103 | $$ LANGUAGE plpgsql; 104 | CREATE TRIGGER testupstrig BEFORE UPDATE ON fs_mqltestdb.employee FOR EACH ROW EXECUTE PROCEDURE testuptrig(); 105 | 106 | 107 | CREATE OR REPLACE FUNCTION testdeltrig() returns trigger 108 | AS $$ 109 | DECLARE 110 | BEGIN 111 | 112 | -- test revert with this 113 | IF OLD.emp_id = 4 THEN 114 | return NULL; 115 | END IF; 116 | 117 | return OLD; 118 | END; 119 | $$ LANGUAGE plpgsql; 120 | 121 | CREATE TRIGGER testdeltrig BEFORE DELETE ON fs_mqltestdb.employee FOR EACH ROW EXECUTE PROCEDURE testdeltrig(); 122 | 123 | 124 | -- create a trigger with notices 125 | CREATE OR REPLACE FUNCTION raise_a_notice() RETURNS TRIGGER AS 126 | $$ 127 | DECLARE 128 | arg TEXT; 129 | BEGIN 130 | RAISE NOTICE 'oh but why args here? count: ''%''?',TG_NARGS; 131 | 132 | FOREACH arg IN ARRAY TG_ARGV LOOP 133 | RAISE NOTICE 'Why would you pass in ''%''?',arg; 134 | END LOOP; 135 | RETURN NEW; -- in plpgsql you must return OLD, NEW, or another record of table's type 136 | END; 137 | $$ LANGUAGE plpgsql; 138 | CREATE TRIGGER no_inserts_without_notices BEFORE INSERT ON fs_mqltestdb.employee FOR EACH ROW EXECUTE PROCEDURE raise_a_notice('spoiled fish','stunned parrots'); 139 | 140 | --select * from information_schema.triggers; 141 | -------------------------------------------------------------------------------- /testexp_mysql_then_pg: -------------------------------------------------------------------------------- 1 | ?column? 2 | --------------- 3 | RUNNING TESTS 4 | (1 row) 5 | 6 | INSERT 0 1 7 | ?column? 8 | -------------------------------------------------------------------------------------------------------------------------------------------------------------- 9 | OUR FIRST OP CAUSED THE PGRTI FIELD TO BE CREATED if we dont wait a few seconds all the operations will be queued before we are done creating the structures 10 | (1 row) 11 | 12 | pg_sleep 13 | ---------- 14 | 15 | (1 row) 16 | 17 | ?column? 18 | ----------------------------------------------------- 19 | check that the before insert trigger runs only once 20 | (1 row) 21 | 22 | INSERT 0 1 23 | emp_id | emp_name | emp_dept_id | trigg_count 24 | --------+------------------------------------------------------------+-------------+------------- 25 | 1 | emp - 1 | 1 | 26 | 2 | MYSQL_first_op | 1 | 27 | 3 | emp - 3 | 1 | 28 | 4 | emp - 4 | 2 | 29 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 30 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 31 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 32 | 8 | firsop_pg insert trigger mod! | 2 | 1 33 | 9 | runoncealice insert trigger mod! | 2 | 1 34 | (9 rows) 35 | 36 | ?column? 37 | ----------------------------- 38 | check before update trigger 39 | (1 row) 40 | 41 | UPDATE 1 42 | emp_id | emp_name | emp_dept_id | trigg_count 43 | --------+------------------------------------------------------------+-------------+------------- 44 | 1 | emp - 1 | 1 | 45 | 2 | MYSQL_first_op | 1 | 46 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 47 | 4 | emp - 4 | 2 | 48 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 49 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 50 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 51 | 8 | firsop_pg insert trigger mod! | 2 | 1 52 | 9 | runoncealice insert trigger mod! | 2 | 1 53 | (9 rows) 54 | 55 | ?column? 56 | ----------------------------------------------------- 57 | check before insert trigger: we cannot insert id 42 58 | (1 row) 59 | 60 | INSERT 0 0 61 | emp_id | emp_name | emp_dept_id | trigg_count 62 | --------+------------------------------------------------------------+-------------+------------- 63 | 1 | emp - 1 | 1 | 64 | 2 | MYSQL_first_op | 1 | 65 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 66 | 4 | emp - 4 | 2 | 67 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 68 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 69 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 70 | 8 | firsop_pg insert trigger mod! | 2 | 1 71 | 9 | runoncealice insert trigger mod! | 2 | 1 72 | (9 rows) 73 | 74 | ?column? 75 | -------------------------------------------------- 76 | check before insert trigger: we can insert id 43 77 | (1 row) 78 | 79 | INSERT 0 1 80 | emp_id | emp_name | emp_dept_id | trigg_count 81 | --------+------------------------------------------------------------+-------------+------------- 82 | 1 | emp - 1 | 1 | 83 | 2 | MYSQL_first_op | 1 | 84 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 85 | 4 | emp - 4 | 2 | 86 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 87 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 88 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 89 | 8 | firsop_pg insert trigger mod! | 2 | 1 90 | 9 | runoncealice insert trigger mod! | 2 | 1 91 | 43 | alice insert trigger mod! | 2 | 1 92 | (10 rows) 93 | 94 | ?column? 95 | ---------------------------------------------------- 96 | check before update trigger: we cannot update id 4 97 | (1 row) 98 | 99 | UPDATE 0 100 | emp_id | emp_name | emp_dept_id | trigg_count 101 | --------+------------------------------------------------------------+-------------+------------- 102 | 1 | emp - 1 | 1 | 103 | 2 | MYSQL_first_op | 1 | 104 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 105 | 4 | emp - 4 | 2 | 106 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 107 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 108 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 109 | 8 | firsop_pg insert trigger mod! | 2 | 1 110 | 9 | runoncealice insert trigger mod! | 2 | 1 111 | 43 | alice insert trigger mod! | 2 | 1 112 | (10 rows) 113 | 114 | ?column? 115 | ---------------------------------------------------- 116 | check before delete trigger: we cannot delete id 4 117 | (1 row) 118 | 119 | DELETE 0 120 | emp_id | emp_name | emp_dept_id | trigg_count 121 | --------+------------------------------------------------------------+-------------+------------- 122 | 1 | emp - 1 | 1 | 123 | 2 | MYSQL_first_op | 1 | 124 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 125 | 4 | emp - 4 | 2 | 126 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 127 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 128 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 129 | 8 | firsop_pg insert trigger mod! | 2 | 1 130 | 9 | runoncealice insert trigger mod! | 2 | 1 131 | 43 | alice insert trigger mod! | 2 | 1 132 | (10 rows) 133 | 134 | ?column? 135 | ------------------ 136 | test delete id 1 137 | (1 row) 138 | 139 | DELETE 1 140 | emp_id | emp_name | emp_dept_id | trigg_count 141 | --------+------------------------------------------------------------+-------------+------------- 142 | 2 | MYSQL_first_op | 1 | 143 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 144 | 4 | emp - 4 | 2 | 145 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 146 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 147 | 7 | MYSQLINSERT-- insert trigger mod! | 2 | 1 148 | 8 | firsop_pg insert trigger mod! | 2 | 1 149 | 9 | runoncealice insert trigger mod! | 2 | 1 150 | 43 | alice insert trigger mod! | 2 | 1 151 | (9 rows) 152 | 153 | -------------------------------------------------------------------------------- /testexp_pg_then_mysql: -------------------------------------------------------------------------------- 1 | emp_id | emp_name | emp_dept_id | trigg_count 2 | --------+------------------------------------------------------------+-------------+------------- 3 | 2 | MYSQL_first_op TRIGGER UPDATED! | 1 | 1 4 | 3 | pgupdate-- TRIGGER UPDATED! | 1 | 1 5 | 4 | emp - 4 | 2 | 6 | 5 | emp - 5 TRIGGER UPDATED! TRIGGER UPDATED! TRIGGER UPDATED! | 1 | 3 7 | 6 | MYSQL2 TRIGGER UPDATED! | 2 | 1 8 | 7 | firsop_pg insert trigger mod! | 2 | 1 9 | 8 | runoncealice insert trigger mod! | 2 | 1 10 | 43 | alice insert trigger mod! | 2 | 1 11 | 44 | MYSQLINSERT-- insert trigger mod! | 2 | 1 12 | (9 rows) 13 | 14 | --------------------------------------------------------------------------------