Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Allow multiple aggregated columns per query #504

Open
wants to merge 10 commits into
base: master
Choose a base branch
from
Prev Previous commit
Next Next commit
Implement allowing multiple aggregated columns per query.
dgeelen-uipath committed Jun 25, 2021
commit 0a5610b46ae33a555da269a2806f9bf2a5f796bd
51 changes: 51 additions & 0 deletions QueryBuilder.Tests/AggregateTests.cs
Original file line number Diff line number Diff line change
@@ -55,6 +55,57 @@ public void SelectAggregateMultipleColumnsAlias()
);
}

[Fact]
public void MultipleAggregatesPerQuery()
{
var query = new Query()
.SelectMin("MinColumn")
.SelectMax("MaxColumn")
.From("Table")
;

var c = Compile(query);

Assert.Equal("SELECT MIN([MinColumn]) AS [min], MAX([MaxColumn]) AS [max] FROM [Table]", c[EngineCodes.SqlServer]);
Assert.Equal("SELECT MIN(`MinColumn`) AS `min`, MAX(`MaxColumn`) AS `max` FROM `Table`", c[EngineCodes.MySql]);
Assert.Equal("SELECT MIN(\"MINCOLUMN\") AS \"MIN\", MAX(\"MAXCOLUMN\") AS \"MAX\" FROM \"TABLE\"", c[EngineCodes.Firebird]);
Assert.Equal("SELECT MIN(\"MinColumn\") AS \"min\", MAX(\"MaxColumn\") AS \"max\" FROM \"Table\"", c[EngineCodes.PostgreSql]);
}

[Fact]
public void AggregatesAndNonAggregatesCanBeMixedInQueries1()
{
var query = new Query()
.Select("ColumnA")
.SelectMax("ColumnB")
.From("Table")
;

var c = Compile(query);

Assert.Equal("SELECT [ColumnA], MAX([ColumnB]) AS [max] FROM [Table]", c[EngineCodes.SqlServer]);
Assert.Equal("SELECT `ColumnA`, MAX(`ColumnB`) AS `max` FROM `Table`", c[EngineCodes.MySql]);
Assert.Equal("SELECT \"COLUMNA\", MAX(\"COLUMNB\") AS \"MAX\" FROM \"TABLE\"", c[EngineCodes.Firebird]);
Assert.Equal("SELECT \"ColumnA\", MAX(\"ColumnB\") AS \"max\" FROM \"Table\"", c[EngineCodes.PostgreSql]);
}

[Fact]
public void AggregatesAndNonAggregatesCanBeMixedInQueries2()
{
var query = new Query()
.SelectMax("ColumnA")
.Select("ColumnB")
.From("Table")
;

var c = Compile(query);

Assert.Equal("SELECT MAX([ColumnA]) AS [max], [ColumnB] FROM [Table]", c[EngineCodes.SqlServer]);
Assert.Equal("SELECT MAX(`ColumnA`) AS `max`, `ColumnB` FROM `Table`", c[EngineCodes.MySql]);
Assert.Equal("SELECT MAX(\"COLUMNA\") AS \"MAX\", \"COLUMNB\" FROM \"TABLE\"", c[EngineCodes.Firebird]);
Assert.Equal("SELECT MAX(\"ColumnA\") AS \"max\", \"ColumnB\" FROM \"Table\"", c[EngineCodes.PostgreSql]);
}

[Fact]
public void SelectCount()
{
7 changes: 3 additions & 4 deletions QueryBuilder.Tests/SelectTests.cs
Original file line number Diff line number Diff line change
@@ -106,10 +106,9 @@ public void ExpandedSelectAs()
var c = Compile(q);

// This result is weird (but valid syntax), and at least it works in
// a somewhat explainable way, as opposed to regular Select() when
// combining the expanded syntax and the 'as' SQLKata keyword support
// which simply silently stops working when the {...} expansion is
// applied.
// a somewhat explainable way. The regular 'as' keyword support in
// Select() does not work when combined with the {...}-expansion
// syntax (the alias will be lost).
Assert.Equal("SELECT [users].[id] AS [Alias], [users].[name] AS [Alias], [users].[age] AS [Alias] FROM [users]", c[EngineCodes.SqlServer]);
Assert.Equal("SELECT `users`.`id` AS `Alias`, `users`.`name` AS `Alias`, `users`.`age` AS `Alias` FROM `users`", c[EngineCodes.MySql]);
}
18 changes: 18 additions & 0 deletions QueryBuilder/Clauses/ColumnClause.cs
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@
using System.Collections.Generic;
using System.Diagnostics;

namespace SqlKata
@@ -59,6 +60,23 @@ public override AbstractClause Clone()
}
}

public class AggregateColumn : AbstractColumn
{
public string Type { get; set; } // Min, Max, etc.
public string Column { get; set; } // Aggregate functions accept only a single 'value expression' (for now we implement only column name)
public override AbstractClause Clone()
{
return new AggregateColumn
{
Engine = Engine,
Component = Component,
Alias = Alias,
Type = Type,
Column = Column,
};
}
}

public class RawColumn : AbstractColumn
{
/// <summary>
5 changes: 5 additions & 0 deletions QueryBuilder/Compilers/Compiler.cs
Original file line number Diff line number Diff line change
@@ -475,6 +475,11 @@ public virtual string CompileColumn(SqlResult ctx, AbstractColumn column)
return "(" + subCtx.RawSql + $"){alias}";
}

if (column is AggregateColumn aggregate)
{
return $"{aggregate.Type.ToUpperInvariant()}({CompileColumn(ctx, new Column { Name = aggregate.Column })}) {ColumnAsKeyword}{WrapValue(aggregate.Alias ?? aggregate.Type)}";
}

if (!string.IsNullOrWhiteSpace(column.Alias))
{
return $"{Wrap((column as Column).Name)} {ColumnAsKeyword}{Wrap(column.Alias)}";
31 changes: 21 additions & 10 deletions QueryBuilder/Query.Aggregate.cs
Original file line number Diff line number Diff line change
@@ -24,19 +24,30 @@ public Query SelectAggregate(string type, IEnumerable<string> columns, string al
throw new System.ArgumentException("Cannot aggregate more than one column at once");
}

Method = "aggregate";

if (this.HasComponent("aggregate"))
if (type != "count" || (columns.Count() == 1 && !this.IsDistinct))
{
throw new System.InvalidOperationException("Cannot add more than one aggregate");
Method = "select";
this.AddComponent("select", new AggregateColumn
{
Alias = alias,
Type = type,
Column = columns.First(),
});
}

this.AddComponent("aggregate", new AggregateClause
else
{
Type = type,
Columns = columns.ToList(),
Alias = alias
});
if (this.HasComponent("aggregate"))
{
throw new System.InvalidOperationException("Cannot add more than one top-level aggregate clause");
}
Method = "aggregate";
this.AddComponent("aggregate", new AggregateClause
{
Alias = alias,
Type = type,
Columns = columns.ToList(),
});
}

return this;
}