From f203f8c9b205542109842f02e9b7e0c080bee82b Mon Sep 17 00:00:00 2001 From: Ahmad Moussawi Date: Sat, 1 Oct 2022 09:42:23 +0300 Subject: [PATCH 1/3] iss-507: add the SelectAggregate method to QueryBuilder --- QueryBuilder/Clauses/ColumnClause.cs | 29 ++++++++++++++ QueryBuilder/Compilers/Compiler.cs | 58 ++++++++++++++++++++++++++-- QueryBuilder/Query.Select.cs | 49 +++++++++++++++++++++++ 3 files changed, 133 insertions(+), 3 deletions(-) diff --git a/QueryBuilder/Clauses/ColumnClause.cs b/QueryBuilder/Clauses/ColumnClause.cs index 58872d8e..dd51a85e 100644 --- a/QueryBuilder/Clauses/ColumnClause.cs +++ b/QueryBuilder/Clauses/ColumnClause.cs @@ -77,4 +77,33 @@ public override AbstractClause Clone() }; } } + + /// + /// Represents an aggregated column clause with an optional filter + /// + /// + public class AggregatedColumn : AbstractColumn + { + /// + /// 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; + public string Aggregate { get; set; } + public AbstractColumn Column { get; set; } + public override AbstractClause Clone() + { + return new AggregatedColumn + { + Engine = Engine, + Filter = Filter?.Clone(), + Column = Column.Clone() as AbstractColumn, + Aggregate = Aggregate, + Component = Component, + }; + } + } } diff --git a/QueryBuilder/Compilers/Compiler.cs b/QueryBuilder/Compilers/Compiler.cs index 69bb1a83..dd65c07b 100644 --- a/QueryBuilder/Compilers/Compiler.cs +++ b/QueryBuilder/Compilers/Compiler.cs @@ -24,6 +24,12 @@ protected Compiler() public virtual string EngineCode { get; } + /// + /// Whether the compiler supports the `SELECT ... FILTER` syntax + /// + /// + public virtual bool SupportsFilterClause { get; set; } = false; + protected virtual string SingleRowDummyTableName { get => null; } /// @@ -512,10 +518,44 @@ public virtual string CompileColumn(SqlResult ctx, AbstractColumn column) return "(" + subCtx.RawSql + $"){alias}"; } + if (column is AggregatedColumn aggregatedColumn) + { + string agg = aggregatedColumn.Aggregate.ToUpperInvariant(); + + var (col, alias) = SplitAlias(CompileColumn(ctx, aggregatedColumn.Column)); + + alias = string.IsNullOrEmpty(alias) ? "" : $" {ColumnAsKeyword}{alias}"; + + string filterCondition = CompileFilterConditions(ctx, aggregatedColumn); + + if (string.IsNullOrEmpty(filterCondition)) + { + return $"{agg}({col}){alias}"; + } + + if (SupportsFilterClause) + { + return $"{agg}({col}) FILTER (WHERE {filterCondition}){alias}"; + } + + return $"{agg}(CASE WHEN {filterCondition} THEN {col} END){alias}"; + } + return Wrap((column as Column).Name); } + protected virtual string CompileFilterConditions(SqlResult ctx, AggregatedColumn aggregatedColumn) + { + if (aggregatedColumn.Filter == null) + { + return null; + } + + var wheres = aggregatedColumn.Filter.GetComponents("where"); + + return CompileConditions(ctx, wheres); + } public virtual SqlResult CompileCte(AbstractFrom cte) { @@ -872,9 +912,7 @@ public virtual string Wrap(string value) if (value.ToLowerInvariant().Contains(" as ")) { - var index = value.ToLowerInvariant().IndexOf(" as "); - var before = value.Substring(0, index); - var after = value.Substring(index + 4); + var (before, after) = SplitAlias(value); return Wrap(before) + $" {ColumnAsKeyword}" + WrapValue(after); } @@ -892,6 +930,20 @@ public virtual string Wrap(string value) return WrapValue(value); } + public virtual (string, string) SplitAlias(string value) + { + var index = value.LastIndexOf(" as ", StringComparison.OrdinalIgnoreCase); + + if (index > 0) + { + var before = value.Substring(0, index); + var after = value.Substring(index + 4); + return (before, after); + } + + return (value, null); + } + /// /// Wrap a single string in keyword identifiers. /// diff --git a/QueryBuilder/Query.Select.cs b/QueryBuilder/Query.Select.cs index f753a388..9502c024 100644 --- a/QueryBuilder/Query.Select.cs +++ b/QueryBuilder/Query.Select.cs @@ -68,5 +68,54 @@ public Query Select(Func callback, string alias) { return Select(callback.Invoke(NewChild()), alias); } + + public Query SelectAggregate(string aggregate, string column, Query filter = null) + { + Method = "select"; + + AddComponent("select", new AggregatedColumn + { + Column = new Column { Name = column }, + Aggregate = aggregate, + Filter = filter, + }); + + return this; + } + + public Query SelectAggregate(string aggregate, string column, Func filter) + { + if (filter == null) + { + return SelectAggregate(aggregate, column); + } + + return SelectAggregate(aggregate, column, filter.Invoke(NewChild())); + } + + public Query SelectSum(string column, Func filter = null) + { + return SelectAggregate("sum", column, filter); + } + + public Query SelectCount(string column, Func filter = null) + { + return SelectAggregate("count", column, filter); + } + + public Query SelectAvg(string column, Func filter = null) + { + return SelectAggregate("avg", column, filter); + } + + public Query SelectMin(string column, Func filter = null) + { + return SelectAggregate("min", column, filter); + } + + public Query SelectMax(string column, Func filter = null) + { + return SelectAggregate("max", column, filter); + } } } From ea8d2bd53012f41c3ee7cb0b2edff3d3f2b2037f Mon Sep 17 00:00:00 2001 From: Ahmad Moussawi Date: Sat, 1 Oct 2022 09:42:52 +0300 Subject: [PATCH 2/3] iss-507: Enable the filter support for SQLite and PG --- QueryBuilder/Compilers/PostgresCompiler.cs | 1 + QueryBuilder/Compilers/SqliteCompiler.cs | 3 +-- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/QueryBuilder/Compilers/PostgresCompiler.cs b/QueryBuilder/Compilers/PostgresCompiler.cs index 1d52c7f5..3b45d0e6 100644 --- a/QueryBuilder/Compilers/PostgresCompiler.cs +++ b/QueryBuilder/Compilers/PostgresCompiler.cs @@ -11,6 +11,7 @@ public PostgresCompiler() } public override string EngineCode { get; } = EngineCodes.PostgreSql; + public override bool SupportsFilterClause { get; set; } = true; protected override string CompileBasicStringCondition(SqlResult ctx, BasicStringCondition x) diff --git a/QueryBuilder/Compilers/SqliteCompiler.cs b/QueryBuilder/Compilers/SqliteCompiler.cs index 6d8a5d30..1401dd35 100644 --- a/QueryBuilder/Compilers/SqliteCompiler.cs +++ b/QueryBuilder/Compilers/SqliteCompiler.cs @@ -1,6 +1,4 @@ using System.Collections.Generic; -using SqlKata; -using SqlKata.Compilers; namespace SqlKata.Compilers { @@ -10,6 +8,7 @@ public class SqliteCompiler : Compiler protected override string OpeningIdentifier { get; set; } = "\""; protected override string ClosingIdentifier { get; set; } = "\""; protected override string LastId { get; set; } = "select last_insert_rowid() as id"; + public override bool SupportsFilterClause { get; set; } = true; public override string CompileTrue() { From 486754169e99ed622b3aba61c061876287407193 Mon Sep 17 00:00:00 2001 From: Ahmad Moussawi Date: Sat, 1 Oct 2022 09:43:13 +0300 Subject: [PATCH 3/3] iss-507: add more tests --- QueryBuilder.Tests/MySqlExecutionTest.cs | 49 +++++++++++++++++++ QueryBuilder.Tests/SQLiteExecutionTest.cs | 51 ++++++++++++++++++++ QueryBuilder.Tests/SelectTests.cs | 58 ++++++++++++++++++++++- 3 files changed, 156 insertions(+), 2 deletions(-) diff --git a/QueryBuilder.Tests/MySqlExecutionTest.cs b/QueryBuilder.Tests/MySqlExecutionTest.cs index d3aa70c0..07df93c8 100644 --- a/QueryBuilder.Tests/MySqlExecutionTest.cs +++ b/QueryBuilder.Tests/MySqlExecutionTest.cs @@ -200,6 +200,55 @@ public void ExistsShouldReturnTrueForNonEmptyTable() db.Drop("Transaction"); } + [Fact] + public void BasicSelectFilter() + { + var db = DB().Create("Transaction", new[] { + "Id INT PRIMARY KEY AUTO_INCREMENT", + "Date DATE NOT NULL", + "Amount int NOT NULL", + }); + + var data = new Dictionary { + // 2020 + {"2020-01-01", 10}, + {"2020-05-01", 20}, + + // 2021 + {"2021-01-01", 40}, + {"2021-02-01", 10}, + {"2021-04-01", -10}, + + // 2022 + {"2022-01-01", 80}, + {"2022-02-01", -30}, + {"2022-05-01", 50}, + }; + + foreach (var row in data) + { + db.Query("Transaction").Insert(new + { + Date = row.Key, + Amount = row.Value + }); + } + + var query = db.Query("Transaction") + .SelectSum("Amount as Total_2020", q => q.WhereDatePart("year", "date", 2020)) + .SelectSum("Amount as Total_2021", q => q.WhereDatePart("year", "date", 2021)) + .SelectSum("Amount as Total_2022", q => q.WhereDatePart("year", "date", 2022)) + ; + + var results = query.Get().ToList(); + Assert.Single(results); + Assert.Equal(30, results[0].Total_2020); + Assert.Equal(40, results[0].Total_2021); + Assert.Equal(100, results[0].Total_2022); + + db.Drop("Transaction"); + } + QueryFactory DB() { var host = System.Environment.GetEnvironmentVariable("SQLKATA_MYSQL_HOST"); diff --git a/QueryBuilder.Tests/SQLiteExecutionTest.cs b/QueryBuilder.Tests/SQLiteExecutionTest.cs index 7496e702..8c4d43f5 100644 --- a/QueryBuilder.Tests/SQLiteExecutionTest.cs +++ b/QueryBuilder.Tests/SQLiteExecutionTest.cs @@ -207,6 +207,57 @@ public void InlineTable() db.Drop("Transaction"); } + + + [Fact] + public void BasicSelectFilter() + { + var db = DB().Create("Transaction", new[] { + "Id INTEGER PRIMARY KEY AUTOINCREMENT", + "Date DATE NOT NULL", + "Amount int NOT NULL", + }); + + var data = new Dictionary { + // 2020 + {"2020-01-01", 10}, + {"2020-05-01", 20}, + + // 2021 + {"2021-01-01", 40}, + {"2021-02-01", 10}, + {"2021-04-01", -10}, + + // 2022 + {"2022-01-01", 80}, + {"2022-02-01", -30}, + {"2022-05-01", 50}, + }; + + foreach (var row in data) + { + db.Query("Transaction").Insert(new + { + Date = row.Key, + Amount = row.Value + }); + } + + var query = db.Query("Transaction") + .SelectSum("Amount as Total_2020", q => q.WhereDatePart("year", "date", 2020)) + .SelectSum("Amount as Total_2021", q => q.WhereDatePart("year", "date", 2021)) + .SelectSum("Amount as Total_2022", q => q.WhereDatePart("year", "date", 2022)) + ; + + var results = query.Get().ToList(); + Assert.Single(results); + Assert.Equal(30, results[0].Total_2020); + Assert.Equal(40, results[0].Total_2021); + Assert.Equal(100, results[0].Total_2022); + + db.Drop("Transaction"); + } + QueryFactory DB() { var cs = $"Data Source=file::memory:;Cache=Shared"; diff --git a/QueryBuilder.Tests/SelectTests.cs b/QueryBuilder.Tests/SelectTests.cs index 4f96569a..8612a985 100644 --- a/QueryBuilder.Tests/SelectTests.cs +++ b/QueryBuilder.Tests/SelectTests.cs @@ -819,7 +819,7 @@ public void EscapeClauseThrowsForMultipleCharacters() [Fact] public void BasicSelectRaw_WithNoTable() { - var q = new Query().SelectRaw("somefunction() as c1"); + var q = new Query().SelectRaw("somefunction() as c1"); var c = Compilers.CompileFor(EngineCodes.SqlServer, q); Assert.Equal("SELECT somefunction() as c1", c.ToString()); @@ -848,6 +848,60 @@ public void BasicSelect_WithNoTableWhereRawClause() var c = Compilers.CompileFor(EngineCodes.SqlServer, q); Assert.Equal("SELECT [c1] WHERE 1 = 1", c.ToString()); } - + + [Fact] + public void BasicSelectAggregate() + { + var q = new Query("Posts").Select("Title") + .SelectAggregate("sum", "ViewCount"); + + var sqlServer = Compilers.CompileFor(EngineCodes.SqlServer, q); + Assert.Equal("SELECT [Title], SUM([ViewCount]) FROM [Posts]", sqlServer.ToString()); + } + + [Fact] + public void SelectAggregateShouldIgnoreEmptyFilter() + { + var q = new Query("Posts").Select("Title") + .SelectAggregate("sum", "ViewCount", q => q); + + var sqlServer = Compilers.CompileFor(EngineCodes.SqlServer, q); + Assert.Equal("SELECT [Title], SUM([ViewCount]) FROM [Posts]", sqlServer.ToString()); + } + + [Fact] + public void SelectAggregateShouldIgnoreEmptyQueryFilter() + { + var q = new Query("Posts").Select("Title") + .SelectAggregate("sum", "ViewCount", new Query()); + + var sqlServer = Compilers.CompileFor(EngineCodes.SqlServer, q); + Assert.Equal("SELECT [Title], SUM([ViewCount]) FROM [Posts]", sqlServer.ToString()); + } + + [Fact] + public void BasicSelectAggregateWithAlias() + { + var q = new Query("Posts").Select("Title") + .SelectAggregate("sum", "ViewCount as TotalViews"); + + var sqlServer = Compilers.CompileFor(EngineCodes.SqlServer, q); + Assert.Equal("SELECT [Title], SUM([ViewCount]) AS [TotalViews] FROM [Posts]", sqlServer.ToString()); + } + + [Fact] + public void SelectWithFilter() + { + var q = new Query("Posts").Select("Title") + .SelectAggregate("sum", "ViewCount as Published_Jan", q => q.Where("Published_Month", "Jan")) + .SelectAggregate("sum", "ViewCount as Published_Feb", q => q.Where("Published_Month", "Feb")); + + var pgSql = Compilers.CompileFor(EngineCodes.PostgreSql, q); + Assert.Equal("SELECT \"Title\", SUM(\"ViewCount\") FILTER (WHERE \"Published_Month\" = 'Jan') AS \"Published_Jan\", SUM(\"ViewCount\") FILTER (WHERE \"Published_Month\" = 'Feb') AS \"Published_Feb\" FROM \"Posts\"", pgSql.ToString()); + + var sqlServer = Compilers.CompileFor(EngineCodes.SqlServer, q); + Assert.Equal("SELECT [Title], SUM(CASE WHEN [Published_Month] = 'Jan' THEN [ViewCount] END) AS [Published_Jan], SUM(CASE WHEN [Published_Month] = 'Feb' THEN [ViewCount] END) AS [Published_Feb] FROM [Posts]", sqlServer.ToString()); + } + } }