Skip to content

Commit 75772b9

Browse files
Copilotmathiasrw
andauthored
Let GROUP BY support table-prefixed columns in arithmetic expressions to fix #536 (#2297)
Co-authored-by: copilot-swe-agent[bot] <198982749+Copilot@users.noreply.github.com> Co-authored-by: mathiasrw <1063454+mathiasrw@users.noreply.github.com>
1 parent 39cfeb5 commit 75772b9

File tree

2 files changed

+83
-1
lines changed

2 files changed

+83
-1
lines changed

src/50expression.js

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -734,7 +734,11 @@
734734
}
735735

736736
if (context === 'g') {
737-
return `g['${this.nick}']`;
737+
// When accessing grouped columns, use columnid (without table prefix) if nick is not set
738+
// This handles cases like: SELECT a.id + 1 FROM ... GROUP BY a.id
739+
// where the column in the expression doesn't have nick set, but the group stores it by columnid
740+
const nickToUse = this.nick || this.columnid;
741+
return `g['${nickToUse}']`;
738742
}
739743

740744
if (this.tableid) {

test/test536-B.js

Lines changed: 78 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,78 @@
1+
if (typeof exports === 'object') {
2+
var assert = require('assert');
3+
var alasql = require('..');
4+
}
5+
6+
describe('Test 536 - GROUP BY on field of type INTEGER with table prefix', function () {
7+
const test = '536B';
8+
9+
before(function () {
10+
alasql('create database test' + test);
11+
alasql('use test' + test);
12+
});
13+
14+
after(function () {
15+
alasql('drop database test' + test);
16+
});
17+
18+
it('A) Simple GROUP BY with arithmetic on INTEGER field (baseline)', function () {
19+
alasql('create table data( id INTEGER PRIMARY KEY, grp INTEGER)');
20+
alasql('insert into data select range._ as id , range._ % 3 as grp from RANGE(0,9)as range');
21+
22+
var res = alasql('select id, id +1 as id_plus_1 from data group by id');
23+
24+
// Check that the arithmetic operation works correctly
25+
assert.strictEqual(res.length, 10);
26+
assert.strictEqual(res[0].id, 0);
27+
assert.strictEqual(res[0].id_plus_1, 1);
28+
assert.strictEqual(res[1].id, 1);
29+
assert.strictEqual(res[1].id_plus_1, 2);
30+
assert.strictEqual(res[9].id, 9);
31+
assert.strictEqual(res[9].id_plus_1, 10);
32+
});
33+
34+
it('B) GROUP BY with table prefix in SELECT arithmetic operations', function () {
35+
alasql('create table data2( id INTEGER PRIMARY KEY, grp INTEGER)');
36+
alasql('insert into data2 select range._ as id , range._ % 3 as grp from RANGE(0,9)as range');
37+
38+
// This is the failing case from the issue
39+
var res = alasql(
40+
'select a.id, a.id +1 as id_plus_1, CAST(a.id AS INTEGER) +1 as cast_plus_1 ' +
41+
'from data2 as a, data2 as b ' +
42+
'where a.id < b.id and a.grp = b.grp ' +
43+
'group by a.id'
44+
);
45+
46+
// Should have 7 rows (0,1,2,3,4,5,6 have matching pairs)
47+
assert.strictEqual(res.length, 7);
48+
49+
// Check first row
50+
assert.strictEqual(res[0].id, 0);
51+
assert.strictEqual(res[0].id_plus_1, 1, 'a.id + 1 should equal 1 for id=0');
52+
assert.strictEqual(res[0].cast_plus_1, 1, 'CAST(a.id AS INTEGER) + 1 should equal 1 for id=0');
53+
54+
// Check another row
55+
assert.strictEqual(res[2].id, 2);
56+
assert.strictEqual(res[2].id_plus_1, 3, 'a.id + 1 should equal 3 for id=2');
57+
assert.strictEqual(res[2].cast_plus_1, 3, 'CAST(a.id AS INTEGER) + 1 should equal 3 for id=2');
58+
});
59+
60+
it('C) GROUP BY with table prefix - without table prefix in expressions (workaround)', function () {
61+
alasql('create table data3( id INTEGER PRIMARY KEY, grp INTEGER)');
62+
alasql('insert into data3 select range._ as id , range._ % 3 as grp from RANGE(0,9)as range');
63+
64+
// The workaround mentioned in the issue - use column names without table prefix in expressions
65+
var res = alasql(
66+
'select a.id, (id +1) as id_plus_1, CAST(id AS INTEGER) +1 as cast_plus_1 ' +
67+
'from data3 as a, data3 as b ' +
68+
'where a.id < b.id and a.grp = b.grp ' +
69+
'group by a.id'
70+
);
71+
72+
// Should work correctly
73+
assert.strictEqual(res.length, 7);
74+
assert.strictEqual(res[0].id, 0);
75+
assert.strictEqual(res[0].id_plus_1, 1);
76+
assert.strictEqual(res[0].cast_plus_1, 1);
77+
});
78+
});

0 commit comments

Comments
 (0)