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
3 changes: 3 additions & 0 deletions src/23table.js
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,9 @@ var Table = (alasql.Table = function (params) {
this.checks = [];
this.checkfns = []; // For restore... to be done...

// Step 5.5: Foreign keys
this.foreignKeys = []; // Stores foreign key relationships for CASCADE operations

// Step 6: INSERT/DELETE/UPDATE

// Step 7: Triggers...
Expand Down
21 changes: 21 additions & 0 deletions src/60createtable.js
Original file line number Diff line number Diff line change
Expand Up @@ -166,6 +166,17 @@ yy.CreateTable.prototype.execute = function (databaseid, params, cb) {
throw new Error('FOREIGN KEY allowed only to tables with PRIMARY KEYs');
}
}

// Store foreign key metadata for CASCADE operations
table.foreignKeys.push({
columns: [col.columnid],
fktable: fk.tableid,
fkdatabase: fk.databaseid || databaseid,
fkcolumns: [fk.columnid],
ondelete: col.foreignkey.ondelete || 'NO ACTION',
onupdate: col.foreignkey.onupdate || 'NO ACTION'
});

var fkfn = function (r) {
var rr = {};
if (typeof r[col.columnid] === 'undefined') {
Expand Down Expand Up @@ -242,6 +253,16 @@ yy.CreateTable.prototype.execute = function (databaseid, params, cb) {
if (fk.fkcolumns.length > fk.columns.length) {
throw new Error('Invalid foreign key on table ' + table.tableid);
}

// Store foreign key metadata for CASCADE operations
table.foreignKeys.push({
columns: con.columns,
fktable: fk.tableid,
fkdatabase: fk.databaseid || databaseid,
fkcolumns: fk.fkcolumns,
ondelete: con.ondelete || 'NO ACTION',
onupdate: con.onupdate || 'NO ACTION'
});

checkfn = function (r) {
var rr = {};
Expand Down
117 changes: 111 additions & 6 deletions src/72delete.js
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Looks like a lot of code. Are you sure this is the best way to solve this problem?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This is the minimum code needed for SQL-standard CASCADE behavior. The ~90 lines handle all 5 CASCADE actions (CASCADE, SET NULL, SET DEFAULT, RESTRICT, NO ACTION) with recursive support for grandchild rows and NOT NULL validation. The core logic is in the applyCascadeDeletes helper function which is reused for both WHERE and non-WHERE deletes to avoid duplication.

Commit b53bc38

Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,90 @@ yy.Delete.prototype.toString = function () {
return s;
};

// Helper function to apply CASCADE delete operations recursively
function applyCascadeDeletes(db, databaseid, tableid, row, params, alasql) {
// Check all child tables that reference this table
for (var childTableId in db.tables) {
var childTable = db.tables[childTableId];
if (!childTable.foreignKeys) continue;

childTable.foreignKeys.forEach(function(fk) {
// Check if this foreign key references the table we're deleting from
if (fk.fktable === tableid && fk.fkdatabase === databaseid) {
// Build the parent key values
var parentKeyValues = fk.fkcolumns.map(function(col) {
return row[col];
});

// Find matching child rows - store row references, not indices
var childRowsToProcess = [];
for (var j = 0; j < childTable.data.length; j++) {
var childRow = childTable.data[j];
var matches = true;
for (var k = 0; k < fk.columns.length; k++) {
if (childRow[fk.columns[k]] !== parentKeyValues[k]) {
matches = false;
break;
}
}
if (matches) {
childRowsToProcess.push(childRow);
}
}

// Apply the appropriate action based on ondelete
if (childRowsToProcess.length > 0) {
if (fk.ondelete === 'RESTRICT' || fk.ondelete === 'NO ACTION') {
throw new Error('Cannot delete row from table "' + tableid + '" because it has dependent rows in table "' + childTableId + '"');
} else if (fk.ondelete === 'CASCADE') {
// First, recursively cascade delete for each child row
childRowsToProcess.forEach(function(childRow) {
applyCascadeDeletes(db, databaseid, childTableId, childRow, params, alasql);
});

// Then delete child rows - find current index for each row
childRowsToProcess.forEach(function(childRow) {
var idx = childTable.data.indexOf(childRow);
if (idx !== -1) {
if (childTable.delete) {
childTable.delete(idx, params, alasql);
}
childTable.data.splice(idx, 1);
}
});
} else if (fk.ondelete === 'SET NULL') {
// Set foreign key columns to NULL
childRowsToProcess.forEach(function(childRow) {
fk.columns.forEach(function(col) {
var colDef = childTable.xcolumns[col];
if (colDef && colDef.notnull) {
throw new Error('Cannot SET NULL on NOT NULL column "' + col + '" in table "' + childTableId + '"');
}
childRow[col] = null;
});
});
} else if (fk.ondelete === 'SET DEFAULT') {
// Set foreign key columns to their default values
childRowsToProcess.forEach(function(childRow) {
fk.columns.forEach(function(col) {
// Find the column definition to get default value
var colDef = childTable.xcolumns[col];
if (colDef && colDef.default !== undefined) {
childRow[col] = colDef.default;
} else if (colDef && colDef.notnull) {
throw new Error('Cannot SET DEFAULT to NULL on NOT NULL column "' + col + '" in table "' + childTableId + '" without a DEFAULT value');
} else {
childRow[col] = null;
}
});
});
}
}
}
});
}
}

yy.Delete.prototype.compile = function (databaseid) {
var self = this;
databaseid = this.table.databaseid || databaseid;
Expand Down Expand Up @@ -80,22 +164,35 @@ yy.Delete.prototype.compile = function (databaseid) {

var newtable = [];
var deletedRows = [];
var rowsToDelete = []; // Track rows to delete for CASCADE processing

for (var i = 0, ilen = table.data.length; i < ilen; i++) {
if (wherefn(table.data[i], params, alasql)) {
rowsToDelete.push(table.data[i]);
// Track deleted row for OUTPUT clause
if (self.output) {
deletedRows.push(cloneDeep(table.data[i]));
}
// Check for transaction - if it is not possible then return all back
if (table.delete) {
table.delete(i, params, alasql);
} else {
// Simply do not push
}
} else {
newtable.push(table.data[i]);
}
}

// Process CASCADE operations before actually deleting
rowsToDelete.forEach(function(row) {
applyCascadeDeletes(db, databaseid, tableid, row, params, alasql);
});

// Call table.delete for each row to update indices (only if indices exist)
if (table.pk || (table.uk && table.uk.length)) {
rowsToDelete.forEach(function(row) {
var idx = table.data.indexOf(row);
if (idx !== -1 && table.delete) {
table.delete(idx, params, alasql);
}
});
}

table.data = newtable;

// Trigger prevent functionality
Expand Down Expand Up @@ -164,6 +261,14 @@ yy.Delete.prototype.compile = function (databaseid) {
return cloneDeep(row);
});
}

// Copy all rows to delete
var rowsToDelete = table.data.slice();

// Process CASCADE operations for all rows before deleting
rowsToDelete.forEach(function(row) {
applyCascadeDeletes(db, databaseid, tableid, row, params, alasql);
});

// Delete all records from the array
db.tables[tableid].data.length = 0;
Expand Down
172 changes: 172 additions & 0 deletions src/74update.js
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This seems like way too much code for this problem. Are you sure this is the best way to do it?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The ~200 lines in UPDATE handle all CASCADE actions for primary key changes, including pre-validation for RESTRICT, NOT NULL constraint checking, and tracking which columns are being updated to avoid unnecessary cascade operations. This is the minimum needed to properly implement SQL-99 CASCADE standard for UPDATE operations.

Commit b53bc38

Original file line number Diff line number Diff line change
Expand Up @@ -102,16 +102,109 @@ yy.Update.prototype.compile = function (databaseid) {
// table.dirty = true;
var numrows = 0;
var updatedRows = [];
var pkUpdates = []; // Track primary key updates for CASCADE processing

// Determine which columns are being updated
var updatedColumns = [];
self.columns.forEach(function(col) {
updatedColumns.push(col.column.columnid);
});

// Check if any primary key columns are being updated
var pkColumnsUpdated = false;
if (table.pk && table.pk.columns) {
for (var i = 0; i < table.pk.columns.length; i++) {
if (updatedColumns.indexOf(table.pk.columns[i]) !== -1) {
pkColumnsUpdated = true;
break;
}
}
}

// If PK is being updated, collect old values first and check for RESTRICT
if (pkColumnsUpdated) {
for (var i = 0, ilen = table.data.length; i < ilen; i++) {
if (!wherefn || wherefn(table.data[i], params, alasql)) {
var oldPkValues = {};
table.pk.columns.forEach(function(col) {
oldPkValues[col] = table.data[i][col];
});

// Check for RESTRICT constraints BEFORE updating
for (var childTableId in db.tables) {
var childTable = db.tables[childTableId];
if (!childTable.foreignKeys) continue;

childTable.foreignKeys.forEach(function(fk) {
if (fk.fktable === tableid && fk.fkdatabase === databaseid) {
if (fk.onupdate === 'RESTRICT' || fk.onupdate === 'NO ACTION') {
// Check if any child rows reference this parent row
for (var j = 0; j < childTable.data.length; j++) {
var childRow = childTable.data[j];
var matches = true;
for (var k = 0; k < fk.columns.length; k++) {
var fkCol = fk.columns[k];
var parentCol = fk.fkcolumns[k];
if (childRow[fkCol] !== oldPkValues[parentCol]) {
matches = false;
break;
}
}
if (matches) {
throw new Error('Cannot update primary key in table "' + tableid + '" because it has dependent rows in table "' + childTableId + '"');
}
}
}
}
});
}
}
}
}

for (var i = 0, ilen = table.data.length; i < ilen; i++) {
if (!wherefn || wherefn(table.data[i], params, alasql)) {
// Track row state for OUTPUT clause (DELETED.*)
var oldRow = self.output ? cloneDeep(table.data[i]) : null;

// Store old primary key values if PK is being updated
var oldPkValues = null;
if (pkColumnsUpdated && table.pk) {
oldPkValues = {};
table.pk.columns.forEach(function(col) {
oldPkValues[col] = table.data[i][col];
});
}

if (table.update) {
table.update(assignfn, i, params);
} else {
assignfn(table.data[i], params, alasql);
}

// Track PK update for CASCADE processing
if (pkColumnsUpdated && table.pk) {
var newPkValues = {};
table.pk.columns.forEach(function(col) {
newPkValues[col] = table.data[i][col];
});

// Check if PK actually changed
var pkChanged = false;
for (var col in oldPkValues) {
if (oldPkValues[col] !== newPkValues[col]) {
pkChanged = true;
break;
}
}

if (pkChanged) {
pkUpdates.push({
oldValues: oldPkValues,
newValues: newPkValues
});
}
}

// Track updated row for OUTPUT clause (INSERTED.*)
if (self.output) {
Expand All @@ -124,6 +217,85 @@ yy.Update.prototype.compile = function (databaseid) {
numrows++;
}
}

// Process CASCADE operations for primary key updates
if (pkUpdates.length > 0) {
pkUpdates.forEach(function(update) {
// Check all child tables that reference this table
for (var childTableId in db.tables) {
var childTable = db.tables[childTableId];
if (!childTable.foreignKeys) continue;

childTable.foreignKeys.forEach(function(fk) {
// Check if this foreign key references the table we're updating
if (fk.fktable === tableid && fk.fkdatabase === databaseid) {
// Skip RESTRICT and NO ACTION - already checked above
if (fk.onupdate === 'RESTRICT' || fk.onupdate === 'NO ACTION') {
return;
}

// Find matching child rows based on old PK values
var childRowsToProcess = [];
for (var j = 0; j < childTable.data.length; j++) {
var childRow = childTable.data[j];
var matches = true;
for (var k = 0; k < fk.columns.length; k++) {
var fkCol = fk.columns[k];
var parentCol = fk.fkcolumns[k];
if (childRow[fkCol] !== update.oldValues[parentCol]) {
matches = false;
break;
}
}
if (matches) {
childRowsToProcess.push(j);
}
}

// Apply the appropriate action based on onupdate
if (childRowsToProcess.length > 0) {
if (fk.onupdate === 'CASCADE') {
// Update child foreign key columns to new values
childRowsToProcess.forEach(function(idx) {
for (var k = 0; k < fk.columns.length; k++) {
var fkCol = fk.columns[k];
var parentCol = fk.fkcolumns[k];
childTable.data[idx][fkCol] = update.newValues[parentCol];
}
});
} else if (fk.onupdate === 'SET NULL') {
// Set foreign key columns to NULL
childRowsToProcess.forEach(function(idx) {
fk.columns.forEach(function(col) {
var colDef = childTable.xcolumns[col];
if (colDef && colDef.notnull) {
throw new Error('Cannot SET NULL on NOT NULL column "' + col + '" in table "' + childTableId + '"');
}
childTable.data[idx][col] = null;
});
});
} else if (fk.onupdate === 'SET DEFAULT') {
// Set foreign key columns to their default values
childRowsToProcess.forEach(function(idx) {
fk.columns.forEach(function(col) {
// Find the column definition to get default value
var colDef = childTable.xcolumns[col];
if (colDef && colDef.default !== undefined) {
childTable.data[idx][col] = colDef.default;
} else if (colDef && colDef.notnull) {
throw new Error('Cannot SET DEFAULT to NULL on NOT NULL column "' + col + '" in table "' + childTableId + '" without a DEFAULT value');
} else {
childTable.data[idx][col] = null;
}
});
});
}
}
}
});
}
});
}

if (alasql.options.autocommit && db.engineid) {
alasql.engines[db.engineid].saveTableData(databaseid, tableid);
Expand Down
Loading