diff --git a/QueryBuilder.Tests/AggregateTests.cs b/QueryBuilder.Tests/AggregateTests.cs index 68a69842..96e48c38 100644 --- a/QueryBuilder.Tests/AggregateTests.cs +++ b/QueryBuilder.Tests/AggregateTests.cs @@ -1,5 +1,6 @@ using SqlKata.Compilers; using SqlKata.Tests.Infrastructure; +using System.Collections.Generic; using Xunit; namespace SqlKata.Tests @@ -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() { 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]); + + } } } diff --git a/QueryBuilder/Clauses/ConditionClause.cs b/QueryBuilder/Clauses/ConditionClause.cs index 287149e5..832e4a18 100644 --- a/QueryBuilder/Clauses/ConditionClause.cs +++ b/QueryBuilder/Clauses/ConditionClause.cs @@ -336,4 +336,46 @@ public override AbstractClause Clone() }; } } + + public class AggregatedCondition : AbstractCondition + { + /// + /// Gets or sets the a query that used to filter the data, + /// the compiler will consider only the `Where` clause. + /// + /// + /// The filter query. + /// + public Query Filter { get; set; } = null; + + /// + /// Gets or sets the keyword of aggregate function. + /// + /// + /// The keyword of aggregate function, e.g. "COUNT(DISTINCT columnName)", "COUNT(ALL columnName)", etc. + /// + 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, + }; + } + } } diff --git a/QueryBuilder/Compilers/Compiler.Conditions.cs b/QueryBuilder/Compilers/Compiler.Conditions.cs index 6615c246..a75f7fe0 100644 --- a/QueryBuilder/Compilers/Compiler.Conditions.cs +++ b/QueryBuilder/Compilers/Compiler.Conditions.cs @@ -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}"; + + } + } } diff --git a/QueryBuilder/Compilers/Compiler.cs b/QueryBuilder/Compilers/Compiler.cs index aa15c789..eda3b67a 100644 --- a/QueryBuilder/Compilers/Compiler.cs +++ b/QueryBuilder/Compilers/Compiler.cs @@ -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("where"); + + return CompileCondition(ctx, wheres); + } + public virtual SqlResult CompileCte(AbstractFrom cte) { var ctx = new SqlResult(); @@ -794,18 +804,18 @@ public virtual string CompileOrders(SqlResult ctx) var columns = ctx.Query .GetComponents("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); } @@ -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); + } + /// /// Wrap a single string in keyword identifiers. /// diff --git a/QueryBuilder/Query.Having.cs b/QueryBuilder/Query.Having.cs index ee367941..022c5aa4 100644 --- a/QueryBuilder/Query.Having.cs +++ b/QueryBuilder/Query.Having.cs @@ -652,5 +652,259 @@ public Query OrHavingNotTime(string column, object value) } #endregion + + #region aggregate + private Query HavingAggregate(string aggregate, string column = null, string op = null, object value = null, string keyword = null, Query filter = null) + { + return AddComponent("having", new AggregatedCondition + { + Aggregate = aggregate, + Keyword = keyword, + Column = column, + Operator = op, + Value = value, + Filter = filter, + IsOr = GetOr(), + IsNot = GetNot(), + }); + } + + private Query HavingAggregate(string aggregate, Func filter, string keyword = null) + { + if (filter is null) + return NewQuery(); + + Query queryFilter = queryFilter = filter.Invoke(NewQuery()); + + // omit empty queries + if (!queryFilter.Clauses.Where(x => x.Component == "where").Any()) + { + return (Query)this; + } + + return HavingAggregate(aggregate: aggregate, keyword: keyword, filter: queryFilter); + } + + public Query HavingMin(string column, string op, object value) + { + return HavingAggregate("MIN", column, op, value); + } + + public Query HavingMin(Func filter) + { + return HavingAggregate("MIN", filter); + } + + public Query HavingMax(string column, string op, object value) + { + return HavingAggregate("MAX", column, op, value); + } + + public Query HavingMax(Func filter) + { + return HavingAggregate("MAX", filter); + } + + public Query HavingCount(string column, string op, object value) + { + return HavingAggregate("COUNT", column, op, value); + } + + public Query HavingCount(Func filter) + { + return HavingAggregate("COUNT", filter); + } + + public Query HavingDistinctCount(string column, string op, object value) + { + return HavingAggregate("COUNT", column, op, value, "DISTINCT"); + } + + public Query HavingDistinctCount(Func filter) + { + return HavingAggregate("COUNT", filter, "DISTINCT"); + } + + public Query HavingAllCount(string column, string op, object value) + { + return HavingAggregate("COUNT", column, op, value, "ALL"); + } + + public Query HavingAllCount(Func filter) + { + return HavingAggregate("COUNT", filter, "ALL"); + } + + public Query HavingSum(string column, string op, object value) + { + return HavingAggregate("SUM", column, op, value); + } + + public Query HavingSum(Func filter) + { + return HavingAggregate("SUM", filter); + } + + public Query HavingDistinctSum(string column, string op, object value) + { + return HavingAggregate("SUM", column, op, value, "DISTINCT"); + } + + public Query HavingDistinctSum(Func filter) + { + return HavingAggregate("SUM", filter, "DISTINCT"); + } + + public Query HavingAllSum(string column, string op, object value) + { + return HavingAggregate("SUM", column, op, value, "ALL"); + } + + public Query HavingAllSum(Func filter) + { + return HavingAggregate("SUM", filter, "ALL"); + } + + public Query HavingAvg(string column, string op, object value) + { + return HavingAggregate("AVG", column, op, value); + } + + public Query HavingAvg(Func filter) + { + return HavingAggregate("AVG", filter); + } + + public Query HavingDistinctAvg(string column, string op, object value) + { + return HavingAggregate("AVG", column, op, value, "DISTINCT"); + } + + public Query HavingDistinctAvg(Func filter) + { + return HavingAggregate("AVG", filter, "DISTINCT"); + } + + public Query HavingAllAvg(string column, string op, object value) + { + return HavingAggregate("AVG", column, op, value, "ALL"); + } + + public Query HavingAllAvg(Func filter) + { + return HavingAggregate("AVG", filter, "ALL"); + } + + + public Query OrHavingMin(string column, string op, object value) + { + return Or().HavingAggregate("MIN", column, op, value); + } + + public Query OrHavingMin(Func filter) + { + return Or().HavingAggregate("MIN", filter); + } + + public Query OrHavingMax(string column, string op, object value) + { + return Or().HavingAggregate("MAX", column, op, value); + } + + public Query OrHavingMax(Func filter) + { + return Or().HavingAggregate("MAX", filter); + } + + public Query OrHavingCount(string column, string op, object value) + { + return Or().HavingAggregate("COUNT", column, op, value); + } + + public Query OrHavingCount(Func filter) + { + return Or().HavingAggregate("COUNT", filter); + } + + public Query OrHavingDistinctCount(string column, string op, object value) + { + return Or().HavingAggregate("COUNT", column, op, value, "DISTINCT"); + } + + public Query OrHavingDistinctCount(Func filter) + { + return Or().HavingAggregate("COUNT", filter, "DISTINCT"); + } + + public Query OrHavingAllCount(string column, string op, object value) + { + return Or().HavingAggregate("COUNT", column, op, value, "ALL"); + } + + public Query OrHavingAllCount(Func filter) + { + return Or().HavingAggregate("COUNT", filter, "ALL"); + } + + public Query OrHavingSum(string column, string op, object value) + { + return Or().HavingAggregate("SUM", column, op, value); + } + + public Query OrHavingSum(Func filter) + { + return Or().HavingAggregate("SUM", filter); + } + + public Query OrHavingDistinctSum(string column, string op, object value) + { + return Or().HavingAggregate("SUM", column, op, value, "DISTINCT"); + } + + public Query OrHavingDistinctSum(Func filter) + { + return Or().HavingAggregate("SUM", filter, "DISTINCT"); + } + + public Query OrHavingAllSum(string column, string op, object value) + { + return Or().HavingAggregate("SUM", column, op, value, "ALL"); + } + + public Query OrHavingAllSum(Func filter) + { + return Or().HavingAggregate("SUM", filter, "ALL"); + } + + public Query OrHavingAvg(string column, string op, object value) + { + return Or().HavingAggregate("AVG", column, op, value); + } + + public Query OrHavingAvg(Func filter) + { + return Or().HavingAggregate("AVG", filter); + } + + public Query OrHavingDistinctAvg(string column, string op, object value) + { + return Or().HavingAggregate("AVG", column, op, value, "DISTINCT"); + } + + public Query OrHavingDistinctAvg(Func filter) + { + return Or().HavingAggregate("AVG", filter, "DISTINCT"); + } + + public Query OrHavingAllAvg(string column, string op, object value) + { + return Or().HavingAggregate("AVG", column, op, value, "ALL"); + } + + public Query OrHavingAllAvg(Func filter) + { + return Or().HavingAggregate("AVG", filter, "ALL"); + } + #endregion } }