Skip to content
Merged
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
49 changes: 49 additions & 0 deletions QueryBuilder.Tests/MySqlExecutionTest.cs
Original file line number Diff line number Diff line change
Expand Up @@ -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<string, int> {
// 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");
Expand Down
51 changes: 51 additions & 0 deletions QueryBuilder.Tests/SQLiteExecutionTest.cs
Original file line number Diff line number Diff line change
Expand Up @@ -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<string, int> {
// 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";
Expand Down
58 changes: 56 additions & 2 deletions QueryBuilder.Tests/SelectTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -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());
Expand Down Expand Up @@ -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());
}

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

/// <summary>
/// Represents an aggregated column clause with an optional filter
/// </summary>
/// <seealso cref="AbstractColumn" />
public class AggregatedColumn : AbstractColumn
{
/// <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;
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,
};
}
}
}
58 changes: 55 additions & 3 deletions QueryBuilder/Compilers/Compiler.cs
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,12 @@ protected Compiler()

public virtual string EngineCode { get; }

/// <summary>
/// Whether the compiler supports the `SELECT ... FILTER` syntax
/// </summary>
/// <value></value>
public virtual bool SupportsFilterClause { get; set; } = false;

protected virtual string SingleRowDummyTableName { get => null; }

/// <summary>
Expand Down Expand Up @@ -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<AbstractCondition>("where");

return CompileConditions(ctx, wheres);
}

public virtual SqlResult CompileCte(AbstractFrom cte)
{
Expand Down Expand Up @@ -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);
}
Expand All @@ -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);
}

/// <summary>
/// Wrap a single string in keyword identifiers.
/// </summary>
Expand Down
1 change: 1 addition & 0 deletions QueryBuilder/Compilers/PostgresCompiler.cs
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down
3 changes: 1 addition & 2 deletions QueryBuilder/Compilers/SqliteCompiler.cs
Original file line number Diff line number Diff line change
@@ -1,6 +1,4 @@
using System.Collections.Generic;
using SqlKata;
using SqlKata.Compilers;

namespace SqlKata.Compilers
{
Expand All @@ -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()
{
Expand Down
49 changes: 49 additions & 0 deletions QueryBuilder/Query.Select.cs
Original file line number Diff line number Diff line change
Expand Up @@ -68,5 +68,54 @@ public Query Select(Func<Query, Query> 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<Query, Query> filter)
{
if (filter == null)
{
return SelectAggregate(aggregate, column);
}

return SelectAggregate(aggregate, column, filter.Invoke(NewChild()));
}

public Query SelectSum(string column, Func<Query, Query> filter = null)
{
return SelectAggregate("sum", column, filter);
}

public Query SelectCount(string column, Func<Query, Query> filter = null)
{
return SelectAggregate("count", column, filter);
}

public Query SelectAvg(string column, Func<Query, Query> filter = null)
{
return SelectAggregate("avg", column, filter);
}

public Query SelectMin(string column, Func<Query, Query> filter = null)
{
return SelectAggregate("min", column, filter);
}

public Query SelectMax(string column, Func<Query, Query> filter = null)
{
return SelectAggregate("max", column, filter);
}
}
}