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
37 changes: 37 additions & 0 deletions src/424select.js
Original file line number Diff line number Diff line change
Expand Up @@ -481,6 +481,25 @@ yy.Select.prototype.compileSelect2 = function (query, params) {

yy.Select.prototype.compileSelectGroup0 = function (query) {
var self = this;

// Build a lookup map for GROUP BY columns that reference aliases (optimization to avoid O(n*m) complexity)
var groupByAliasMap = {};
if (self.group) {
self.group.forEach(function (gp, idx) {
if (gp instanceof yy.Column && gp.columnid && !gp.tableid) {
groupByAliasMap[gp.columnid] = idx;
}
});
}

// Build a set of actual column names in SELECT to distinguish from pure aliases
var selectColumnNames = {};
self.columns.forEach(function (col) {
if (col instanceof yy.Column && col.columnid) {
selectColumnNames[col.columnid] = true;
}
});
Comment on lines +486 to +501
Copy link
Member

Choose a reason for hiding this comment

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

Are we sure this is the most efficient way?


self.columns.forEach(function (col, idx) {
if (!(col instanceof yy.Column && col.columnid === '*')) {
var colas;
Expand All @@ -501,12 +520,30 @@ yy.Select.prototype.compileSelectGroup0 = function (query) {
col.nick = colas;

if (self.group) {
// Match GROUP BY columns to SELECT columns by columnid and tableid (for real columns)
var groupIdx = self.group.findIndex(function (gp) {
return gp.columnid === col.columnid && gp.tableid === col.tableid;
});
if (groupIdx > -1) {
self.group[groupIdx].nick = colas;
}

// Also match GROUP BY columns that reference SELECT column aliases
// This handles cases like: SELECT CASE ... END AS age_group ... GROUP BY age_group
// Only apply if:
// 1. The SELECT column has an alias
// 2. That alias matches a GROUP BY column name
// 3. The alias is NOT an actual column name (pure alias, not renaming)
if (col.as && groupByAliasMap.hasOwnProperty(col.as) && !selectColumnNames[col.as]) {
var aliasGroupIdx = groupByAliasMap[col.as];
// Replace the GROUP BY column reference with a deep copy of the SELECT expression
// We use deep cloning to ensure nested objects (like CASE whens/elses) are copied
var groupExpr = cloneDeep(col);
// Clear SELECT-specific properties that shouldn't be in GROUP BY
delete groupExpr.as;
groupExpr.nick = colas;
self.group[aliasGroupIdx] = groupExpr;
}
}

if (
Expand Down
155 changes: 155 additions & 0 deletions test/test2361.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,155 @@
if (typeof exports === 'object') {
var assert = require('assert');
var alasql = require('..');
}

describe('Test 2361 - GROUP BY with CASE expression alias', function () {
const test = '2361';

before(function () {
alasql('create database test' + test);
alasql('use test' + test);
});

after(function () {
alasql('drop database test' + test);
});

it('A) GROUP BY with CASE WHEN aliased expression', function () {
// Create test data with ages
var data = [{age: 25}, {age: 26}, {age: 35}, {age: 36}, {age: 45}, {age: 55}];

var result = alasql(
`SELECT
CASE
WHEN age BETWEEN 20 AND 29 THEN '20-29'
WHEN age BETWEEN 30 AND 39 THEN '30-39'
WHEN age BETWEEN 40 AND 49 THEN '40-49'
WHEN age BETWEEN 50 AND 59 THEN '50-59'
ELSE '60+'
END AS age_group,
COUNT(*) AS customer_count
FROM ?
GROUP BY age_group
ORDER BY age_group`,
[data]
);

var expected = [
{age_group: '20-29', customer_count: 2},
{age_group: '30-39', customer_count: 2},
{age_group: '40-49', customer_count: 1},
{age_group: '50-59', customer_count: 1},
];

assert.deepEqual(result, expected);
});

it('B) GROUP BY with CASE WHEN and ELSE clause', function () {
var data = [{age: 10}, {age: 20}, {age: 30}, {age: 100}];

var result = alasql(
`SELECT
CASE
WHEN age BETWEEN 0 AND 9 THEN '0-9'
WHEN age BETWEEN 10 AND 19 THEN '10-19'
WHEN age BETWEEN 20 AND 29 THEN '20-29'
ELSE '30+'
END AS age_group
FROM ?
GROUP BY age_group`,
[data]
);

// Should return three unique groups, not just '30+'
var expected = [{age_group: '10-19'}, {age_group: '20-29'}, {age_group: '30+'}];

assert.deepEqual(result.sort(), expected.sort());
});

it('C) GROUP BY with function expression alias', function () {
var data = [{name: 'Alice'}, {name: 'alice'}, {name: 'Bob'}, {name: 'bob'}];

var result = alasql(
`SELECT
UPPER(name) AS upper_name,
COUNT(*) AS cnt
FROM ?
GROUP BY upper_name
ORDER BY upper_name`,
[data]
);

var expected = [
{upper_name: 'ALICE', cnt: 2},
{upper_name: 'BOB', cnt: 2},
];

assert.deepEqual(result, expected);
});

it('D) GROUP BY with multiple CASE expressions', function () {
var data = [
{age: 25, score: 85},
{age: 26, score: 90},
{age: 35, score: 85},
{age: 36, score: 90},
];

var result = alasql(
`SELECT
CASE
WHEN age BETWEEN 20 AND 29 THEN '20-29'
ELSE '30+'
END AS age_group,
CASE
WHEN score >= 90 THEN 'High'
ELSE 'Low'
END AS score_group,
COUNT(*) AS cnt
FROM ?
GROUP BY age_group, score_group
ORDER BY age_group, score_group`,
[data]
);

var expected = [
{age_group: '20-29', score_group: 'High', cnt: 1},
{age_group: '20-29', score_group: 'Low', cnt: 1},
{age_group: '30+', score_group: 'High', cnt: 1},
{age_group: '30+', score_group: 'Low', cnt: 1},
];

assert.deepEqual(result, expected);
});

it('E) GROUP BY with WHERE and CASE expression alias', function () {
var data = [
{age: 25, active: true},
{age: 26, active: false},
{age: 35, active: true},
{age: 36, active: true},
];

var result = alasql(
`SELECT
CASE
WHEN age BETWEEN 20 AND 29 THEN '20-29'
ELSE '30+'
END AS age_group,
COUNT(*) AS cnt
FROM ?
WHERE active = true
GROUP BY age_group
ORDER BY age_group`,
[data]
);

var expected = [
{age_group: '20-29', cnt: 1},
{age_group: '30+', cnt: 2},
];

assert.deepEqual(result, expected);
});
});