Skip to content

Commit 4eddc73

Browse files
Copilotmathiasrw
andauthored
Allow nested subqueries for IN clause to fix #847 (#2187)
Co-authored-by: copilot-swe-agent[bot] <[email protected]> Co-authored-by: mathiasrw <[email protected]> Co-authored-by: Mathias Wulff <[email protected]>
1 parent f9f6e75 commit 4eddc73

File tree

4 files changed

+136
-6
lines changed

4 files changed

+136
-6
lines changed

src/40select.js

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -390,6 +390,15 @@ yy.Select = class Select {
390390
query.queriesfn = this.queries.map(function (q) {
391391
var nq = q.compile(query.database.databaseid);
392392
nq.query.modifier = 'RECORDSET';
393+
// If the nested query has its own queries, ensure they're compiled too
394+
// This handles nested subqueries properly
395+
if (q.queries && q.queries.length > 0) {
396+
nq.query.queriesfn = q.queries.map(function (qq) {
397+
var nnq = qq.compile(query.database.databaseid);
398+
nnq.query.modifier = 'RECORDSET';
399+
return nnq;
400+
});
401+
}
393402
return nq;
394403
});
395404
}

src/alasqlparser.jison

Lines changed: 27 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1582,8 +1582,16 @@ Op
15821582
| Expression CondOp AllSome LPAR Select RPAR
15831583
{
15841584
if(!yy.queries) yy.queries = [];
1585-
$$ = new yy.Op({left:$1, op:$2 , allsome:$3, right:$5, queriesidx: yy.queries.length});
1585+
// Collect any nested queries that belong to this SELECT
1586+
var nestedQueries = yy.queries.slice();
1587+
yy.queries = [];
1588+
// Assign nested queries to the SELECT
1589+
if(nestedQueries.length > 0) {
1590+
$5.queries = nestedQueries;
1591+
}
1592+
// Now add this SELECT to parent queries
15861593
yy.queries.push($5);
1594+
$$ = new yy.Op({left:$1, op:$2 , allsome:$3, right:$5, queriesidx: yy.queries.length - 1});
15871595
}
15881596

15891597
| Expression CondOp AllSome LPAR ExprList RPAR
@@ -1639,15 +1647,31 @@ Op
16391647
| Expression IN LPAR Select RPAR
16401648
{
16411649
if(!yy.queries) yy.queries = [];
1642-
$$ = new yy.Op({left: $1, op:'IN', right:$4, queriesidx: yy.queries.length});
1650+
// Collect any nested queries that belong to this SELECT
1651+
var nestedQueries = yy.queries.slice();
1652+
yy.queries = [];
1653+
// Assign nested queries to the SELECT
1654+
if(nestedQueries.length > 0) {
1655+
$4.queries = nestedQueries;
1656+
}
1657+
// Now add this SELECT to parent queries
16431658
yy.queries.push($4);
1659+
$$ = new yy.Op({left: $1, op:'IN', right:$4, queriesidx: yy.queries.length - 1});
16441660
}
16451661

16461662
| Expression NOT IN LPAR Select RPAR
16471663
{
16481664
if(!yy.queries) yy.queries = [];
1649-
$$ = new yy.Op({left: $1, op:'NOT IN', right:$5, queriesidx: yy.queries.length});
1665+
// Collect any nested queries that belong to this SELECT
1666+
var nestedQueries = yy.queries.slice();
1667+
yy.queries = [];
1668+
// Assign nested queries to the SELECT
1669+
if(nestedQueries.length > 0) {
1670+
$5.queries = nestedQueries;
1671+
}
1672+
// Now add this SELECT to parent queries
16501673
yy.queries.push($5);
1674+
$$ = new yy.Op({left: $1, op:'NOT IN', right:$5, queriesidx: yy.queries.length - 1});
16511675
}
16521676

16531677
| Expression IN LPAR ExprList RPAR

src/alasqlparser.js

Lines changed: 27 additions & 3 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

test/test847.js

Lines changed: 73 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,73 @@
1+
// Test for nested subqueries - Issue: Nested SubQueries do not work as expected
2+
if (typeof exports === 'object') {
3+
var assert = require('assert');
4+
var alasql = require('..');
5+
}
6+
7+
describe('Test 847 - Nested Subqueries', function () {
8+
before(function () {
9+
alasql(`
10+
DROP TABLE IF EXISTS cities;
11+
DROP TABLE IF EXISTS countries;
12+
DROP TABLE IF EXISTS population;
13+
14+
CREATE TABLE cities (city string, population number);
15+
INSERT INTO cities VALUES ('Rome',2863223), ('Paris',2249975), ('Berlin',3517424), ('Madrid',3041579),('Easingwold',4627);
16+
17+
CREATE TABLE countries (name string, population number, city string);
18+
INSERT INTO countries VALUES ('Italy', 89764679009, 'Rome'), ('France', 165247191, 'Paris'), ('Germany', 346186257, 'Berlin');
19+
20+
CREATE TABLE population (number int);
21+
INSERT INTO population VALUES (89764679009), (165247191);
22+
`);
23+
});
24+
25+
after(function () {
26+
alasql(`
27+
DROP TABLE IF EXISTS cities;
28+
DROP TABLE IF EXISTS countries;
29+
DROP TABLE IF EXISTS population;
30+
`);
31+
});
32+
33+
it('1. Nested subqueries in IN clause should work', function () {
34+
var result = alasql(
35+
'SELECT * FROM cities WHERE city IN (SELECT DISTINCT city FROM countries WHERE population IN (SELECT DISTINCT number from population))'
36+
);
37+
38+
assert.equal(result.length, 2, 'Should return 2 cities');
39+
assert.equal(result[0].city, 'Rome', 'First city should be Rome');
40+
assert.equal(result[1].city, 'Paris', 'Second city should be Paris');
41+
});
42+
43+
it('2. Single level subquery should still work', function () {
44+
var result = alasql('SELECT * FROM cities WHERE city IN (SELECT city FROM countries)');
45+
46+
assert.equal(result.length, 3, 'Should return 3 cities');
47+
});
48+
49+
it('3. Triple nested subqueries should work', function () {
50+
alasql(`
51+
CREATE TABLE level3 (val int);
52+
INSERT INTO level3 VALUES (89764679009);
53+
`);
54+
55+
var result = alasql(
56+
'SELECT * FROM cities WHERE city IN (SELECT DISTINCT city FROM countries WHERE population IN (SELECT DISTINCT number from population WHERE number IN (SELECT val FROM level3)))'
57+
);
58+
59+
assert.equal(result.length, 1, 'Should return 1 city');
60+
assert.equal(result[0].city, 'Rome', 'City should be Rome');
61+
62+
alasql('DROP TABLE IF EXISTS level3');
63+
});
64+
65+
it('4. Nested subqueries with NOT IN should work', function () {
66+
var result = alasql(
67+
'SELECT * FROM cities WHERE city NOT IN (SELECT DISTINCT city FROM countries WHERE population NOT IN (SELECT DISTINCT number from population))'
68+
);
69+
70+
// Should return cities that are either not in countries, or in countries with population in the population table
71+
assert(result.length > 0, 'Should return some results');
72+
});
73+
});

0 commit comments

Comments
 (0)