diff --git a/QueryBuilder.Tests/SelectTests.cs b/QueryBuilder.Tests/SelectTests.cs index 3f3c28ba..7048a551 100644 --- a/QueryBuilder.Tests/SelectTests.cs +++ b/QueryBuilder.Tests/SelectTests.cs @@ -930,6 +930,18 @@ public void SelectWithExists_OmitSelectIsFalse() var sqlServer = compiler.Compile(q).ToString(); Assert.Equal("SELECT * FROM [Posts] WHERE EXISTS (SELECT [Id] FROM [Comments] WHERE [Comments].[PostId] = [Posts].[Id])", sqlServer.ToString()); } + [Fact] + public void SelectWithDatePart() + { + var q = new Query().From("users as u").SelectDatePart("day","date","date_day"); + var c = Compile(q); + Assert.Equal("SELECT DAY(`date`) AS `date_day` FROM `users` AS `u`", c[EngineCodes.MySql]); + Assert.Equal("SELECT strftime('%d', \"date\") AS \"date_day\" FROM \"users\" AS \"u\"", c[EngineCodes.Sqlite]); + Assert.Equal("SELECT DAY(`date`) AS `date_day` FROM `users` AS `u`", c[EngineCodes.MySql]); + Assert.Equal("SELECT EXTRACT(DAY FROM \"DATE\") AS \"DATE_DAY\" FROM \"USERS\" AS \"U\"", c[EngineCodes.Firebird]); + Assert.Equal("SELECT DATEPART(DAY, [date]) AS [date_day] FROM [users] AS [u]", c[EngineCodes.SqlServer]); + Assert.Equal("SELECT EXTRACT(DAY FROM \"date\") \"date_day\" FROM \"users\" \"u\"", c[EngineCodes.Oracle]); + } } } diff --git a/QueryBuilder.Tests/SqlServer/SqlServerTests.cs b/QueryBuilder.Tests/SqlServer/SqlServerTests.cs index 3adb84f5..3f8dcf6d 100644 --- a/QueryBuilder.Tests/SqlServer/SqlServerTests.cs +++ b/QueryBuilder.Tests/SqlServer/SqlServerTests.cs @@ -58,5 +58,20 @@ public void OffsetSqlServer_Should_Be_Incremented_By_One(int offset) "SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS [row_num] FROM [users]) AS [results_wrapper] WHERE [row_num] >= " + (offset + 1), c.ToString()); } + + [Fact] + public void SqlServerOrderByTimePart() + { + var query = new Query("table").OrderByDatePart("year","field"); + var result = compiler.Compile(query); + Assert.Equal("SELECT * FROM [table] ORDER BY DATEPART(YEAR, [field])", result.Sql); + } + [Fact] + public void SqlServerGroupByTimePart() + { + var query = new Query("table").GroupByDatePart("year", "field").SelectDatePart("year","field","meow"); + var result = compiler.Compile(query); + Assert.Equal("SELECT DATEPART(YEAR, [field]) AS [meow] FROM [table] GROUP BY DATEPART(YEAR, [field])", result.Sql); + } } } diff --git a/QueryBuilder/Clauses/ColumnClause.cs b/QueryBuilder/Clauses/ColumnClause.cs index dd51a85e..9318e889 100644 --- a/QueryBuilder/Clauses/ColumnClause.cs +++ b/QueryBuilder/Clauses/ColumnClause.cs @@ -29,6 +29,27 @@ public override AbstractClause Clone() }; } } + /// + /// Represents date column clause calculated using query. + /// + public class DateQueryColumn : Column + { + public string Column { get; set; } + + public string Part { get; set; } + + public override AbstractClause Clone() + { + return new DateQueryColumn + { + Engine = Engine, + Name=Name, + Column = Column, + Component = Component, + Part = Part, + }; + } + } /// /// Represents column clause calculated using query. diff --git a/QueryBuilder/Clauses/OrderClause.cs b/QueryBuilder/Clauses/OrderClause.cs index 69af772e..9a07f6ec 100644 --- a/QueryBuilder/Clauses/OrderClause.cs +++ b/QueryBuilder/Clauses/OrderClause.cs @@ -4,7 +4,23 @@ public abstract class AbstractOrderBy : AbstractClause { } + public class DateOrderBy : OrderBy + { + public string Part { get; set; } + /// + public override AbstractClause Clone() + { + return new DateOrderBy + { + Engine = Engine, + Component = Component, + Column = Column, + Part= Part, + Ascending = Ascending + }; + } + } public class OrderBy : AbstractOrderBy { public string Column { get; set; } diff --git a/QueryBuilder/Compilers/Compiler.cs b/QueryBuilder/Compilers/Compiler.cs index aa15c789..05e54f33 100644 --- a/QueryBuilder/Compilers/Compiler.cs +++ b/QueryBuilder/Compilers/Compiler.cs @@ -227,6 +227,16 @@ protected virtual SqlResult CompileSelectQuery(Query query) return ctx; } + + protected virtual string CompileBasicDateSelect(SqlResult ctx, DateQueryColumn x) + { + var column = Wrap(x.Column); + + var sql = $"{x.Part.ToUpperInvariant()}({column})"; + + return sql; + } + protected virtual SqlResult CompileAdHocQuery(AdHocTableFromClause adHoc) { var ctx = new SqlResult(); @@ -531,7 +541,19 @@ public virtual string CompileColumn(SqlResult ctx, AbstractColumn column) return "(" + subCtx.RawSql + $"){alias}"; } + if (column is DateQueryColumn dateQueryColumn) + { + var alias = ""; + if (!string.IsNullOrWhiteSpace(dateQueryColumn.Name)) + { + alias = $" {ColumnAsKeyword}{WrapValue(dateQueryColumn.Name)}"; + } + + var subCtx = CompileBasicDateSelect(ctx,dateQueryColumn); + + return subCtx + $"{alias}"; + } if (column is AggregatedColumn aggregatedColumn) { string agg = aggregatedColumn.Aggregate.ToUpperInvariant(); @@ -801,6 +823,14 @@ public virtual string CompileOrders(SqlResult ctx) ctx.Bindings.AddRange(raw.Bindings); return WrapIdentifiers(raw.Expression); } + if (x is DateOrderBy dateOrderBy) + { + var direct = dateOrderBy.Ascending ? "" : " DESC"; + + var sql = CompileBasicDateSelect(ctx, new DateQueryColumn { Column = dateOrderBy.Column, Part = dateOrderBy.Part }); + + return sql + direct; + } var direction = (x as OrderBy).Ascending ? "" : " DESC"; diff --git a/QueryBuilder/Compilers/FirebirdCompiler.cs b/QueryBuilder/Compilers/FirebirdCompiler.cs index 61ab9547..e16bda9b 100644 --- a/QueryBuilder/Compilers/FirebirdCompiler.cs +++ b/QueryBuilder/Compilers/FirebirdCompiler.cs @@ -73,6 +73,28 @@ protected override string CompileColumns(SqlResult ctx) return compiled; } + protected override string CompileBasicDateSelect(SqlResult ctx, DateQueryColumn x) + { + var column = Wrap(x.Column); + + string left; + + if (x.Part == "time") + { + left = $"CAST({column} as TIME)"; + } + else if (x.Part == "date") + { + left = $"CAST({column} as DATE)"; + } + else + { + left = $"EXTRACT({x.Part.ToUpperInvariant()} FROM {column})"; + } + + return left; + } + protected override string CompileBasicDateCondition(SqlResult ctx, BasicDateCondition condition) { var column = Wrap(condition.Column); diff --git a/QueryBuilder/Compilers/OracleCompiler.cs b/QueryBuilder/Compilers/OracleCompiler.cs index 610ec20d..60c055b6 100644 --- a/QueryBuilder/Compilers/OracleCompiler.cs +++ b/QueryBuilder/Compilers/OracleCompiler.cs @@ -99,7 +99,34 @@ internal void ApplyLegacyLimit(SqlResult ctx) ctx.RawSql = newSql; } + protected override string CompileBasicDateSelect(SqlResult ctx, DateQueryColumn x) + { + var column = Wrap(x.Column); + string sql; + switch (x.Part) + { + case "date": // assume YY-MM-DD format + sql = $"TO_CHAR({column}, 'YY-MM-DD')"; + break; + case "time": + sql = $"TO_CHAR({column}, 'HH24:MI:SS')"; + break; + case "year": + case "month": + case "day": + case "hour": + case "minute": + case "second": + sql = $"EXTRACT({x.Part.ToUpperInvariant()} FROM {column})"; + break; + default: + sql = column; + break; + } + + return sql; + } protected override string CompileBasicDateCondition(SqlResult ctx, BasicDateCondition condition) { diff --git a/QueryBuilder/Compilers/PostgresCompiler.cs b/QueryBuilder/Compilers/PostgresCompiler.cs index 3b45d0e6..3c29de66 100644 --- a/QueryBuilder/Compilers/PostgresCompiler.cs +++ b/QueryBuilder/Compilers/PostgresCompiler.cs @@ -66,6 +66,28 @@ protected override string CompileBasicStringCondition(SqlResult ctx, BasicString } + protected override string CompileBasicDateSelect(SqlResult ctx, DateQueryColumn x) + { + + var column = Wrap(x.Column); + + string left; + + if (x.Part == "time") + { + left = $"{column}::time"; + } + else if (x.Part == "date") + { + left = $"{column}::date"; + } + else + { + left = $"DATE_PART('{x.Part.ToUpperInvariant()}', {column})"; + } + + return left; + } protected override string CompileBasicDateCondition(SqlResult ctx, BasicDateCondition condition) { diff --git a/QueryBuilder/Compilers/SqlServerCompiler.cs b/QueryBuilder/Compilers/SqlServerCompiler.cs index 0202f0f1..416ac9b0 100644 --- a/QueryBuilder/Compilers/SqlServerCompiler.cs +++ b/QueryBuilder/Compilers/SqlServerCompiler.cs @@ -144,7 +144,24 @@ public override string CompileFalse() { return "cast(0 as bit)"; } + protected override string CompileBasicDateSelect(SqlResult ctx, DateQueryColumn x) + { + var column = Wrap(x.Column); + var part = x.Part.ToUpperInvariant(); + + string left; + if (part == "TIME" || part == "DATE") + { + left = $"CAST({column} AS {part.ToUpperInvariant()})"; + } + else + { + left = $"DATEPART({part.ToUpperInvariant()}, {column})"; + } + + return left; + } protected override string CompileBasicDateCondition(SqlResult ctx, BasicDateCondition condition) { var column = Wrap(condition.Column); diff --git a/QueryBuilder/Compilers/SqliteCompiler.cs b/QueryBuilder/Compilers/SqliteCompiler.cs index 1401dd35..b95993c7 100644 --- a/QueryBuilder/Compilers/SqliteCompiler.cs +++ b/QueryBuilder/Compilers/SqliteCompiler.cs @@ -19,7 +19,29 @@ public override string CompileFalse() { return "0"; } + protected override string CompileBasicDateSelect(SqlResult ctx, DateQueryColumn x) + { + var column = Wrap(x.Column); + var formatMap = new Dictionary { + { "date", "%Y-%m-%d" }, + { "time", "%H:%M:%S" }, + { "year", "%Y" }, + { "month", "%m" }, + { "day", "%d" }, + { "hour", "%H" }, + { "minute", "%M" }, + }; + + if (!formatMap.ContainsKey(x.Part)) + { + return column; + } + + var sql = $"strftime('{formatMap[x.Part]}', {column})"; + + return sql; + } public override string CompileLimit(SqlResult ctx) { var limit = ctx.Query.GetLimit(EngineCode); diff --git a/QueryBuilder/Query.Select.cs b/QueryBuilder/Query.Select.cs index 9502c024..3f5289b2 100644 --- a/QueryBuilder/Query.Select.cs +++ b/QueryBuilder/Query.Select.cs @@ -117,5 +117,27 @@ public Query SelectMax(string column, Func filter = null) { return SelectAggregate("max", column, filter); } + + #region date + public Query SelectDatePart(string part, string column,string alias) + { + return AddComponent("select", new DateQueryColumn + { + Name = alias, + Part = part?.ToLowerInvariant(), + Column=column + }); + } + + public Query SelectDate(string column, string alias) + { + return SelectDatePart("date", column, alias); + } + public Query SelectTime(string column, string alias) + { + return SelectDatePart("time", column, alias); + } + #endregion + } } diff --git a/QueryBuilder/Query.cs b/QueryBuilder/Query.cs index 8435eca6..56abb3e6 100755 --- a/QueryBuilder/Query.cs +++ b/QueryBuilder/Query.cs @@ -335,7 +335,64 @@ public Query GroupByRaw(string expression, params object[] bindings) return this; } + #region date + public Query OrderByDatePart(string part, string column) + { + return AddComponent("order", new DateOrderBy + { + Part = part?.ToLowerInvariant(), + Column = column, + Ascending = true + }); + } + + public Query OrderByDate(string column) + { + return OrderByDatePart("date", column); + } + public Query OrderByTime(string column) + { + return OrderByDatePart("time", column); + } + + public Query OrderByDatePartDesc(string part, string column) + { + return AddComponent("order", new DateOrderBy + { + Part = part?.ToLowerInvariant(), + Column = column, + Ascending = true + }); + } + + public Query OrderByDateDesc(string column) + { + return OrderByDatePartDesc("date", column); + } + public Query OrderByTimeDesc(string column) + { + return OrderByDatePartDesc("time", column); + } + + public Query GroupByDatePart(string part, string column) + { + return AddComponent("group", new DateQueryColumn + { + Part = part?.ToLowerInvariant(), + Column = column + }); + } + + public Query GroupByDate(string column) + { + return OrderByDatePart("date", column); + } + public Query GroupByTime(string column) + { + return OrderByDatePart("time", column); + } + #endregion public override Query NewQuery() { return new Query();