Skip to content

Aggregate functions condition support added to Having Queries #624

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

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
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
57 changes: 57 additions & 0 deletions QueryBuilder.Tests/AggregateTests.cs
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
using SqlKata.Compilers;
using SqlKata.Tests.Infrastructure;
using System.Collections.Generic;
using Xunit;

namespace SqlKata.Tests
Expand Down Expand Up @@ -88,5 +89,61 @@ public void Min()

Assert.Equal("SELECT MIN([LatencyMs]) AS [min] FROM [A]", c[EngineCodes.SqlServer]);
}

[Fact]
public void HavingAggregate()
{
var query = new Query().From("TABLENAME").GroupBy("Title").HavingSum("Title", ">", 21).OrHavingAvg("Title", ">", 21).HavingCount("Title", ">", 21).Select("Title");

var compiler = Compile(query);

Assert.Equal("SELECT [Title] FROM [TABLENAME] GROUP BY [Title] HAVING SUM([Title]) > 21 OR AVG([Title]) > 21 AND COUNT([Title]) > 21", compiler[EngineCodes.SqlServer]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(\"Title\") > 21 OR AVG(\"Title\") > 21 AND COUNT(\"Title\") > 21", compiler[EngineCodes.PostgreSql]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(\"Title\") > 21 OR AVG(\"Title\") > 21 AND COUNT(\"Title\") > 21", compiler[EngineCodes.Oracle]);

Assert.Equal("SELECT `Title` FROM `TABLENAME` GROUP BY `Title` HAVING SUM(`Title`) > 21 OR AVG(`Title`) > 21 AND COUNT(`Title`) > 21", compiler[EngineCodes.MySql]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(\"Title\") > 21 OR AVG(\"Title\") > 21 AND COUNT(\"Title\") > 21", compiler[EngineCodes.Sqlite]);
}

[Fact]
public void HavingAggregateWithKeyword()
{
var query = new Query().From("TABLENAME").GroupBy("Title").HavingDistinctSum("Title", ">", 21).OrHavingAllCount("Title", ">", 21).Select("Title");

var compiler = Compile(query);

Assert.Equal("SELECT [Title] FROM [TABLENAME] GROUP BY [Title] HAVING SUM(DISTINCT [Title]) > 21 OR COUNT(ALL [Title]) > 21", compiler[EngineCodes.SqlServer]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(DISTINCT \"Title\") > 21 OR COUNT(ALL \"Title\") > 21", compiler[EngineCodes.PostgreSql]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(DISTINCT \"Title\") > 21 OR COUNT(ALL \"Title\") > 21", compiler[EngineCodes.Oracle]);

Assert.Equal("SELECT `Title` FROM `TABLENAME` GROUP BY `Title` HAVING SUM(DISTINCT `Title`) > 21 OR COUNT(ALL `Title`) > 21", compiler[EngineCodes.MySql]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(DISTINCT \"Title\") > 21 OR COUNT(ALL \"Title\") > 21", compiler[EngineCodes.Sqlite]);

}

[Fact]
public void HavingAggregateWithFilter()
{
var query = new Query().From("TABLENAME").GroupBy("Title").HavingSum(d => d.WhereIn("Title", new List<int>() { 11, 12, 13 })).OrHavingAvg(d => d.WhereBetween("Title", 11, 12)).HavingCount(d => d.WhereLike("Title", "having")).HavingCount(d => d).Select("Title");

var compiler = Compile(query);

Assert.Equal("SELECT [Title] FROM [TABLENAME] GROUP BY [Title] HAVING SUM([Title]) IN (11, 12, 13) OR AVG([Title]) BETWEEN 11 AND 12 AND COUNT(LOWER([Title])) like 'having'", compiler[EngineCodes.SqlServer]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(\"Title\") IN (11, 12, 13) OR AVG(\"Title\") BETWEEN 11 AND 12 AND COUNT(\"Title\") ilike 'having'", compiler[EngineCodes.PostgreSql]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(\"Title\") IN (11, 12, 13) OR AVG(\"Title\") BETWEEN 11 AND 12 AND COUNT(LOWER(\"Title\")) like 'having'", compiler[EngineCodes.Oracle]);

Assert.Equal("SELECT `Title` FROM `TABLENAME` GROUP BY `Title` HAVING SUM(`Title`) IN (11, 12, 13) OR AVG(`Title`) BETWEEN 11 AND 12 AND COUNT(LOWER(`Title`)) like 'having'", compiler[EngineCodes.MySql]);

Assert.Equal("SELECT \"Title\" FROM \"TABLENAME\" GROUP BY \"Title\" HAVING SUM(\"Title\") IN (11, 12, 13) OR AVG(\"Title\") BETWEEN 11 AND 12 AND COUNT(LOWER(\"Title\")) like 'having'", compiler[EngineCodes.Sqlite]);

}
}
}
42 changes: 42 additions & 0 deletions QueryBuilder/Clauses/ConditionClause.cs
Original file line number Diff line number Diff line change
Expand Up @@ -336,4 +336,46 @@ public override AbstractClause Clone()
};
}
}

public class AggregatedCondition : AbstractCondition
{
/// <summary>
/// Gets or sets the a query that used to filter the data,
/// the compiler will consider only the `Where` clause.
/// </summary>
/// <value>
/// The filter query.
/// </value>
public Query Filter { get; set; } = null;

/// <summary>
/// Gets or sets the keyword of aggregate function.
/// </summary>
/// <value>
/// The keyword of aggregate function, e.g. "COUNT(DISTINCT columnName)", "COUNT(ALL columnName)", etc.
/// </value>
public string Keyword { get; set; }

public string Aggregate { get; set; }
public string Column { get; set; }
public string Operator { get; set; }
public object Value { get; set; }

public override AbstractClause Clone()
{
return new AggregatedCondition
{
Filter = Filter?.Clone(),
Keyword = Keyword,
Aggregate = Aggregate,
Column = Column,
Operator = Operator,
Value = Value,
IsOr = IsOr,
IsNot = IsNot,
Engine = Engine,
Component = Component,
};
}
}
}
21 changes: 21 additions & 0 deletions QueryBuilder/Compilers/Compiler.Conditions.cs
Original file line number Diff line number Diff line change
Expand Up @@ -262,5 +262,26 @@ protected virtual string CompileExistsCondition(SqlResult ctx, ExistsCondition i

return $"{op} ({subCtx.RawSql})";
}

protected virtual string CompileAggregatedCondition(SqlResult ctx, AggregatedCondition item)
{
if (item is null)
return "";

string aggregate = item.Aggregate.ToUpperInvariant();
string keyword = item.Keyword?.PadRight(item.Keyword.Length + 1, ' ').ToUpperInvariant(); // add one space to char end of keyword string, cause of building query

string filterCondition = CompileHavingFilterConditions(ctx, item);

if (string.IsNullOrEmpty(filterCondition))
{
return $"{aggregate}({keyword}{Wrap(item.Column)}) {item.Operator} {item.Value}";
}

var (column, condition) = SplitCondition(filterCondition);
return $"{aggregate}({keyword}{column}) {condition}";

}

}
}
42 changes: 33 additions & 9 deletions QueryBuilder/Compilers/Compiler.cs
Original file line number Diff line number Diff line change
Expand Up @@ -571,6 +571,16 @@ protected virtual string CompileFilterConditions(SqlResult ctx, AggregatedColumn
return CompileConditions(ctx, wheres);
}

protected virtual string CompileHavingFilterConditions(SqlResult ctx, AggregatedCondition aggregatedCondition)
{
if (aggregatedCondition.Filter is null)
return null;

var wheres = aggregatedCondition.Filter.GetOneComponent<AbstractCondition>("where");

return CompileCondition(ctx, wheres);
}

public virtual SqlResult CompileCte(AbstractFrom cte)
{
var ctx = new SqlResult();
Expand Down Expand Up @@ -794,18 +804,18 @@ public virtual string CompileOrders(SqlResult ctx)
var columns = ctx.Query
.GetComponents<AbstractOrderBy>("order", EngineCode)
.Select(x =>
{

if (x is RawOrderBy raw)
{
ctx.Bindings.AddRange(raw.Bindings);
return WrapIdentifiers(raw.Expression);
}

var direction = (x as OrderBy).Ascending ? "" : " DESC";
if (x is RawOrderBy raw)
{
ctx.Bindings.AddRange(raw.Bindings);
return WrapIdentifiers(raw.Expression);
}

var direction = (x as OrderBy).Ascending ? "" : " DESC";

return Wrap((x as OrderBy).Column) + direction;
});
return Wrap((x as OrderBy).Column) + direction;
});

return "ORDER BY " + string.Join(", ", columns);
}
Expand Down Expand Up @@ -958,6 +968,20 @@ public virtual (string, string) SplitAlias(string value)
return (value, null);
}

public virtual (string, string) SplitCondition(string value)
{
var splitedValueBySpace = value.Trim().Split(' ');

if (splitedValueBySpace.Length > 1)
{
var column = splitedValueBySpace.First().Trim();
var condition = value.Substring(column.Length).Trim();
return (column, condition);
}

return (value, null);
}

/// <summary>
/// Wrap a single string in keyword identifiers.
/// </summary>
Expand Down
Loading