Skip to content
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
115 changes: 111 additions & 4 deletions src/75merge.js
Original file line number Diff line number Diff line change
Expand Up @@ -42,9 +42,116 @@ yy.Merge.prototype.toString = function () {
return s;
};

yy.Merge.prototype.execute = function (databaseid, params, cb) {
var res = 1;
yy.Merge.prototype.compile = function (databaseid) {
var self = this;
databaseid = self.into.databaseid || databaseid;
var db = alasql.databases[databaseid];
var targettableid = self.into.tableid;
var sourcetableid = self.using.tableid;

if (!db.tables[targettableid]) throw new Error("Target table '" + targettableid + "' not found");
if (!db.tables[sourcetableid]) throw new Error("Source table '" + sourcetableid + "' not found");

if (self.exists) self.existsfn = self.exists.map(function (ex) {
var nq = ex.compile(databaseid); nq.query.modifier = 'RECORDSET'; return nq;
});
if (self.queries) self.queriesfn = self.queries.map(function (q) {
var nq = q.compile(databaseid); nq.query.modifier = 'RECORDSET'; return nq;
});

var targetAlias = self.into.as || targettableid;
var sourceAlias = self.using.as || sourcetableid;

// Helper to evaluate expressions in context
var evalInContext = function (expr, targetRow, sourceRow, params) {
var rec = {};
if (targetRow) rec[targetAlias] = targetRow;
if (sourceRow) rec[sourceAlias] = sourceRow;
return new Function('rec', 'params', 'alasql', 'var y; return ' + expr.toJS('rec', ''))(rec, params, alasql);
};

return function (params, cb) {
var db = alasql.databases[databaseid];
if (alasql.options.autocommit && db.engineid) {
alasql.engines[db.engineid].loadTableData(databaseid, targettableid);
alasql.engines[db.engineid].loadTableData(databaseid, sourcetableid);
}

var targetTable = db.tables[targettableid];
var sourceTable = db.tables[sourcetableid];
targetTable.dirty = true;
var count = 0;

// Check if target and source rows match
var rowsMatch = function (t, s) {
return evalInContext(self.on, t, s, params);
};

// Execute first applicable action for a row
var executeAction = function (targetRow, sourceRow, isMatched, isBySource) {
for (var m = 0; m < self.matches.length; m++) {
var match = self.matches[m];
if (match.matched !== isMatched) continue;
if (isMatched && match.bysource) continue;
if (!isMatched && ((isBySource && !match.bysource) || (!isBySource && !match.bytarget))) continue;
if (match.expr && !evalInContext(match.expr, targetRow, sourceRow, params)) continue;

var action = match.action;
if (action.delete) return 'delete';
if (action.update) {
var rec = {}; rec[targetAlias] = targetRow; rec[sourceAlias] = sourceRow;
action.update.forEach(function (set) {
targetRow[set.column.columnid] = evalInContext(set.expression, targetRow, sourceRow, params);
});
return 'update';
}
if (action.insert) {
var newRow = {};
if (action.columns && action.values && action.values[0]) {
action.columns.forEach(function (col, i) {
if (action.values[0][i]) newRow[col.columnid] = evalInContext(action.values[0][i], null, sourceRow, params);
});
} else if (action.defaultvalues && targetTable.defaultfns) {
eval('newRow = {' + targetTable.defaultfns + '}');
}
if (targetTable.defaultfns) {
eval('var defaults = {' + targetTable.defaultfns + '}');
for (var k in defaults) if (!(k in newRow)) newRow[k] = defaults[k];
}
if (targetTable.insert) targetTable.insert(newRow, false, false);
else targetTable.data.push(newRow);
return 'insert';
}
}
return null;
};

// Process target rows
for (var i = 0; i < targetTable.data.length; i++) {
var targetRow = targetTable.data[i];
var sourceRow = sourceTable.data.find(function (s) { return rowsMatch(targetRow, s); });
var action = executeAction(targetRow, sourceRow, !!sourceRow, !sourceRow);
if (action === 'delete') { targetTable.data.splice(i--, 1); count++; }
else if (action === 'update') count++;
}

// Process unmatched source rows
for (var j = 0; j < sourceTable.data.length; j++) {
var sourceRow = sourceTable.data[j];
if (!targetTable.data.some(function (t) { return rowsMatch(t, sourceRow); })) {
if (executeAction(null, sourceRow, false, false) === 'insert') count++;
}
}

if (alasql.options.autocommit && db.engineid) {
alasql.engines[db.engineid].saveTableData(databaseid, targettableid);
}

if (cb) cb(count);
return count;
};
};

if (cb) res = cb(res);
return res;
yy.Merge.prototype.execute = function (databaseid, params, cb) {
return this.compile(databaseid)(params, cb);
};
46 changes: 27 additions & 19 deletions test/test236.js
Original file line number Diff line number Diff line change
Expand Up @@ -46,26 +46,34 @@ describe('Test 236 MERGE', function () {
});

it('2. Merge', function (done) {
var sql = function () {
/*

MERGE [Target] AS T
USING [Source] AS S
ON (T.EmployeeID = S.EmployeeID)
WHEN NOT MATCHED BY TARGET AND S.EmployeeName LIKE 'S%'
THEN INSERT(EmployeeID, EmployeeName) VALUES(S.EmployeeID, S.EmployeeName)
WHEN MATCHED
THEN UPDATE SET T.EmployeeName = S.EmployeeName
WHEN NOT MATCHED BY SOURCE AND T.EmployeeName LIKE 'S%'
THEN DELETE

*/
}
.toString()
.slice(14, -3);
/// console.log(alasql.parse(sql).toString());
var sql = `
MERGE [Target] AS T
USING [Source] AS S
ON (T.EmployeeID = S.EmployeeID)
WHEN NOT MATCHED BY TARGET AND S.EmployeeName LIKE 'S%'
THEN INSERT(EmployeeID, EmployeeName) VALUES(S.EmployeeID, S.EmployeeName)
WHEN MATCHED
THEN UPDATE SET T.EmployeeName = S.EmployeeName
WHEN NOT MATCHED BY SOURCE AND T.EmployeeName LIKE 'S%'
THEN DELETE
`;

// Execute the MERGE
var res = alasql(sql);

// Verify result count (3 rows affected: 1 insert + 2 deletes)
assert.equal(res, 3);

// Verify final table state
var target = alasql('SELECT * FROM [Target] ORDER BY EmployeeID');
assert.deepEqual(target, [
{EmployeeID: 100, EmployeeName: 'Mary'}, // Unchanged (not in source, not matching S%)
// 101 'Sara' deleted (not in source, matches S%)
// 102 'Stefano' deleted (not in source, matches S%)
// 103 'Bob' not inserted (in source but doesn't match S%)
{EmployeeID: 104, EmployeeName: 'Steve'}, // Inserted (not in target, matches S%)
]);

// console.log(res);
done();
});

Expand Down
Loading