Skip to content

Commit 9f42a4e

Browse files
Copilotmathiasrw
andauthored
Support recursive CTE (Common Table Expression) to fix #335 (#2273)
Co-authored-by: copilot-swe-agent[bot] <198982749+Copilot@users.noreply.github.com> Co-authored-by: mathiasrw <1063454+mathiasrw@users.noreply.github.com> Co-authored-by: Mathias Wulff <m@rawu.dk>
1 parent 676798b commit 9f42a4e

File tree

6 files changed

+1108
-768
lines changed

6 files changed

+1108
-768
lines changed

src/17alasql.js

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -126,6 +126,9 @@ alasql.options = {
126126

127127
loopbreak: 100000,
128128

129+
/** Maximum iterations for recursive CTEs to prevent infinite loops */
130+
maxCteIterations: 1000,
131+
129132
/** Whether GETDATE() and NOW() return dates as string. If false, then a Date object is returned */
130133
dateAsString: true,
131134
};

src/40select.js

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -560,6 +560,15 @@ function modify(query, res) {
560560
const keyTextString =
561561
columns && columns.length > 0 ? columns[0].columnid : Object.keys(res[0])[0];
562562
return res.map(row => row[keyTextString]).join('\n');
563+
564+
case 'ALASQL_DETAILS':
565+
// Returns both data and column metadata in a structured format
566+
// Useful for internal operations that need both data and column info in one call
567+
return {
568+
data: res,
569+
columns: columns,
570+
length: res.length,
571+
};
563572
}
564573
return res;
565574
}

src/67withselect.js

Lines changed: 145 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -14,23 +14,162 @@ yy.WithSelect.prototype.toString = function () {
1414
s +=
1515
this.withs
1616
.map(function (w) {
17-
return w.name + ' AS (' + w.select.toString() + ')';
17+
var colStr = '';
18+
if (w.columns) {
19+
colStr =
20+
'(' +
21+
w.columns
22+
.map(function (c) {
23+
return c.columnid;
24+
})
25+
.join(', ') +
26+
')';
27+
}
28+
return (
29+
(w.recursive ? 'RECURSIVE ' : '') + w.name + colStr + ' AS (' + w.select.toString() + ')'
30+
);
1831
})
19-
.join(',') + ' ';
32+
.join(', ') + ' ';
2033
s += this.select.toString();
2134
return s;
2235
};
2336

37+
// Execute a recursive CTE
38+
function executeRecursiveCTE(w, databaseid, params) {
39+
var maxIterations = alasql.options.maxCteIterations || 1000;
40+
var db = alasql.databases[databaseid];
41+
var tableName = w.name;
42+
43+
// Create the CTE table
44+
var tb = (db.tables[tableName] = new Table({
45+
tableid: tableName,
46+
}));
47+
tb.data = [];
48+
49+
var select = w.select;
50+
var anchorSelect, recursiveSelect;
51+
52+
// Check if this is a UNION ALL structure
53+
if (select.unionall) {
54+
// The anchor is the first part, recursive is in unionall
55+
anchorSelect = Object.assign({}, select);
56+
delete anchorSelect.unionall;
57+
recursiveSelect = select.unionall;
58+
} else if (select.union) {
59+
// UNION (without ALL) - less common for recursive CTEs but possible
60+
anchorSelect = Object.assign({}, select);
61+
delete anchorSelect.union;
62+
recursiveSelect = select.union;
63+
} else {
64+
// No recursive part, just execute once
65+
tb.data = select.execute(databaseid, params);
66+
if (w.columns) {
67+
tb.data = renameColumns(tb.data, w.columns);
68+
}
69+
return tb.data;
70+
}
71+
72+
// Determine column names - either from explicit column list or from anchor query
73+
var columnNames;
74+
if (w.columns && w.columns.length > 0) {
75+
columnNames = w.columns.map(function (c) {
76+
return c.columnid;
77+
});
78+
}
79+
80+
// Execute anchor query using ALASQL_DETAILS format to get both data and column metadata in one call
81+
var anchorSelectObj = new yy.Select(anchorSelect);
82+
anchorSelectObj.modifier = 'ALASQL_DETAILS';
83+
var anchorDetails = anchorSelectObj.execute(databaseid, params);
84+
85+
// Get anchor column names from the query result
86+
var anchorColumnNames = anchorDetails.columns.map(function (c) {
87+
return c.columnid;
88+
});
89+
90+
// If explicit column names provided, use them; otherwise use anchor column names
91+
if (!columnNames) {
92+
columnNames = anchorColumnNames;
93+
}
94+
95+
// Map anchor data to target column names (handles both object format and column renaming)
96+
var anchorData = mapColumnsToNames(anchorDetails.data, anchorColumnNames, columnNames);
97+
tb.data = anchorData.slice();
98+
99+
// Iterate with the recursive part
100+
var newRows = anchorData;
101+
var allData = anchorData.slice();
102+
var iteration = 0;
103+
104+
while (newRows.length > 0 && iteration < maxIterations) {
105+
iteration++;
106+
107+
// Recreate the CTE table with only the new rows to avoid query caching issues
108+
delete db.tables[tableName];
109+
tb = db.tables[tableName] = new Table({
110+
tableid: tableName,
111+
});
112+
tb.data = newRows;
113+
114+
// Execute recursive part using ALASQL_DETAILS format
115+
var recursiveSelectObj = new yy.Select(recursiveSelect);
116+
recursiveSelectObj.modifier = 'ALASQL_DETAILS';
117+
var recursiveDetails = recursiveSelectObj.execute(databaseid, params);
118+
119+
// Handle empty result
120+
if (!recursiveDetails.data || recursiveDetails.data.length === 0) {
121+
break;
122+
}
123+
124+
// Get recursive column names and map to target column names by position
125+
var recursiveColumnNames = recursiveDetails.columns.map(function (c) {
126+
return c.columnid;
127+
});
128+
var recursiveData = mapColumnsToNames(recursiveDetails.data, recursiveColumnNames, columnNames);
129+
130+
// Add new rows to the result
131+
newRows = recursiveData;
132+
for (var i = 0; i < newRows.length; i++) {
133+
allData.push(newRows[i]);
134+
}
135+
}
136+
137+
// Set final table data
138+
tb.data = allData;
139+
return allData;
140+
}
141+
142+
// Helper function to map data from source column names to target column names by position
143+
function mapColumnsToNames(data, sourceColumns, targetColumns) {
144+
return data.map(function (row) {
145+
var newRow = {};
146+
for (var i = 0; i < targetColumns.length && i < sourceColumns.length; i++) {
147+
newRow[targetColumns[i]] = row[sourceColumns[i]];
148+
}
149+
return newRow;
150+
});
151+
}
152+
24153
yy.WithSelect.prototype.execute = function (databaseid, params, cb) {
25154
var self = this;
26155
// Create temporary tables
27156
var savedTables = [];
28157
self.withs.forEach(function (w) {
29158
savedTables.push(alasql.databases[databaseid].tables[w.name]);
30-
var tb = (alasql.databases[databaseid].tables[w.name] = new Table({
31-
tableid: w.name,
32-
}));
33-
tb.data = w.select.execute(databaseid, params);
159+
160+
if (w.recursive) {
161+
// Execute recursive CTE
162+
executeRecursiveCTE(w, databaseid, params);
163+
} else {
164+
// Non-recursive CTE - original behavior
165+
var tb = (alasql.databases[databaseid].tables[w.name] = new Table({
166+
tableid: w.name,
167+
}));
168+
tb.data = w.select.execute(databaseid, params);
169+
if (w.columns) {
170+
tb.data = renameColumns(tb.data, w.columns);
171+
}
172+
}
34173
});
35174

36175
var res = 1;

src/alasqlparser.jison

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -207,6 +207,7 @@ DATABASE(S)? return 'DATABASE'
207207
'READ' return 'READ'
208208
'RECORDSET' return 'RECORDSET'
209209
'REDUCE' return 'REDUCE'
210+
'RECURSIVE' return 'RECURSIVE'
210211
'REFERENCES' return 'REFERENCES'
211212
'REGEXP' return 'REGEXP'
212213
'REINDEX' return 'REINDEX'
@@ -496,13 +497,19 @@ WithSelect
496497
WithTablesList
497498
: WithTablesList COMMA WithTable
498499
{ $1.push($3); $$=$1; }
500+
| WithTablesList COMMA RECURSIVE WithTable
501+
{ $4.recursive = true; $1.push($4); $$=$1; }
499502
| WithTable
500503
{ $$ = [$1]; }
504+
| RECURSIVE WithTable
505+
{ $2.recursive = true; $$ = [$2]; }
501506
;
502507

503508
WithTable
504509
: Literal AS LPAR Select RPAR
505510
{ $$ = {name:$1, select:$4}; }
511+
| Literal LPAR ColumnsList RPAR AS LPAR Select RPAR
512+
{ $$ = {name:$1, columns:$3, select:$7}; }
506513
;
507514

508515
/* SELECT */

0 commit comments

Comments
 (0)