Skip to content

Commit

Permalink
DATEDIFF tests & fixes
Browse files Browse the repository at this point in the history
  • Loading branch information
MarkMpn committed Oct 5, 2024
1 parent 84960ce commit 938d142
Show file tree
Hide file tree
Showing 6 changed files with 135 additions and 18 deletions.
68 changes: 68 additions & 0 deletions MarkMpn.Sql4Cds.Engine.Tests/AdoProviderTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -2712,5 +2712,73 @@ public void DateTruncReturnsOriginalDataType(string type, string datePart)
}
}
}

[TestMethod]
public void DateDiffString()
{
// https://learn.microsoft.com/en-us/sql/t-sql/functions/datediff-transact-sql?view=sql-server-ver16#i-finding-difference-between-startdate-and-enddate-as-date-parts-strings
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
-- DOES NOT ACCOUNT FOR LEAP YEARS
DECLARE @date1 DATETIME, @date2 DATETIME, @result VARCHAR(100);
DECLARE @years INT, @months INT, @days INT,
@hours INT, @minutes INT, @seconds INT, @milliseconds INT;
SET @date1 = '1900-01-01 00:00:00.000'
SET @date2 = '2018-12-12 07:08:01.123'
SELECT @years = DATEDIFF(yy, @date1, @date2)
IF DATEADD(yy, -@years, @date2) < @date1
SELECT @years = @years-1
SET @date2 = DATEADD(yy, -@years, @date2)
SELECT @months = DATEDIFF(mm, @date1, @date2)
IF DATEADD(mm, -@months, @date2) < @date1
SELECT @months=@months-1
SET @date2= DATEADD(mm, -@months, @date2)
SELECT @days=DATEDIFF(dd, @date1, @date2)
IF DATEADD(dd, -@days, @date2) < @date1
SELECT @days=@days-1
SET @date2= DATEADD(dd, -@days, @date2)
SELECT @hours=DATEDIFF(hh, @date1, @date2)
IF DATEADD(hh, -@hours, @date2) < @date1
SELECT @hours=@hours-1
SET @date2= DATEADD(hh, -@hours, @date2)
SELECT @minutes=DATEDIFF(mi, @date1, @date2)
IF DATEADD(mi, -@minutes, @date2) < @date1
SELECT @minutes=@minutes-1
SET @date2= DATEADD(mi, -@minutes, @date2)
SELECT @seconds=DATEDIFF(s, @date1, @date2)
IF DATEADD(s, -@seconds, @date2) < @date1
SELECT @seconds=@seconds-1
SET @date2= DATEADD(s, -@seconds, @date2)
SELECT @milliseconds=DATEDIFF(ms, @date1, @date2)
SELECT @result= ISNULL(CAST(NULLIF(@years,0) AS VARCHAR(10)) + ' years,','')
+ ISNULL(' ' + CAST(NULLIF(@months,0) AS VARCHAR(10)) + ' months,','')
+ ISNULL(' ' + CAST(NULLIF(@days,0) AS VARCHAR(10)) + ' days,','')
+ ISNULL(' ' + CAST(NULLIF(@hours,0) AS VARCHAR(10)) + ' hours,','')
+ ISNULL(' ' + CAST(@minutes AS VARCHAR(10)) + ' minutes and','')
+ ISNULL(' ' + CAST(@seconds AS VARCHAR(10))
+ CASE
WHEN @milliseconds > 0
THEN '.' + CAST(@milliseconds AS VARCHAR(10))
ELSE ''
END
+ ' seconds','')
SELECT @result";

var actual = (string)cmd.ExecuteScalar();
Assert.AreEqual("118 years, 11 months, 11 days, 7 hours, 8 minutes and 1.123 seconds", actual);
}
}
}
}
31 changes: 31 additions & 0 deletions MarkMpn.Sql4Cds.Engine.Tests/ExpressionFunctionTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -327,5 +327,36 @@ public void DateTrunc_Values(string datepart, string expected)
var actual = ExpressionFunctions.DateTrunc(datepart, new SqlDateTime2(new DateTime(2021, 12, 8, 11, 30, 15).AddTicks(1234567)), DataTypeHelpers.DateTime2(7));
Assert.AreEqual(expected, actual.Value.ToString("yyyy-MM-dd HH:mm:ss.fffffff"));
}

[DataTestMethod]
[DataRow("year", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("quarter", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("month", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("dayofyear", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("day", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("week", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("weekday", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("hour", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("minute", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("second", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("millisecond", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
[DataRow("microsecond", "2005-12-31 23:59:59.9999999", "2006-01-01 00:00:00.0000000")]
public void DateDiff_1Boundary(string datepart, string startdate, string enddate)
{
// https://learn.microsoft.com/en-us/sql/t-sql/functions/datediff-transact-sql?view=sql-server-ver16#datepart-boundaries
SqlDateParsing.TryParse(startdate, DateFormat.mdy, out SqlDateTimeOffset start);
SqlDateParsing.TryParse(enddate, DateFormat.mdy, out SqlDateTimeOffset end);
var actual = ExpressionFunctions.DateDiff(datepart, start, end, DataTypeHelpers.DateTimeOffset, DataTypeHelpers.DateTimeOffset);
Assert.AreEqual(1, actual);
}

[TestMethod]
public void DateDiff_TimeZone()
{
var dateTime = new DateTime(2024, 10, 5, 12, 0, 0);
var offset = new DateTimeOffset(dateTime, TimeSpan.FromHours(1));
var actual = ExpressionFunctions.DateDiff("hour", new SqlDateTime(dateTime), new SqlDateTimeOffset(offset), DataTypeHelpers.DateTime, DataTypeHelpers.DateTimeOffset);
Assert.AreEqual(-1, actual);
}
}
}
5 changes: 5 additions & 0 deletions MarkMpn.Sql4Cds.Engine/Ado/Sql4CdsError.cs
Original file line number Diff line number Diff line change
Expand Up @@ -795,6 +795,11 @@ internal static Sql4CdsError AdditionOverflow(TSqlFragment fragment, DataTypeRef
return Create(517, fragment, Collation.USEnglish.ToSqlString(GetTypeName(type)));
}

internal static Sql4CdsError UnsupportedDatePart(TSqlFragment fragment, string part, string function)
{
return Create(9806, fragment, (SqlInt32)part.Length, Collation.USEnglish.ToSqlString(part), (SqlInt32)function.Length, Collation.USEnglish.ToSqlString(function));
}

private static string GetTypeName(DataTypeReference type)
{
if (type is SqlDataTypeReference sqlType)
Expand Down
41 changes: 27 additions & 14 deletions MarkMpn.Sql4Cds.Engine/ExpressionFunctions.cs
Original file line number Diff line number Diff line change
Expand Up @@ -306,48 +306,61 @@ public static SqlInt32 DateDiff(SqlString datepart, SqlDateTimeOffset startdate,
if (!TryParseDatePart(datepart.Value, out var interval))
throw new QueryExecutionException(Sql4CdsError.InvalidOptionValue(new StringLiteral { Value = datepart.Value }, "datediff"));

startdate = DateTrunc(datepart, startdate, startdateType);
enddate = DateTrunc(datepart, enddate, enddateType);
if (interval == Engine.DatePart.Nanosecond)
return 0;
else if (interval == Engine.DatePart.TZOffset)
throw new QueryExecutionException(Sql4CdsError.UnsupportedDatePart(null, datepart.Value, "datediff"));

if (interval == Engine.DatePart.WeekDay)
{
startdate = DateTrunc("day", startdate, startdateType);
enddate = DateTrunc("day", enddate, enddateType);
}
else
{
startdate = DateTrunc(datepart, startdate, startdateType);
enddate = DateTrunc(datepart, enddate, enddateType);
}

switch (interval)
{
case Engine.DatePart.Year:
return enddate.Value.Year - startdate.Value.Year;
return enddate.Value.UtcDateTime.Year - startdate.Value.UtcDateTime.Year;

case Engine.DatePart.Quarter:
var endQuarter = enddate.Value.Year * 4 + (enddate.Value.Month - 1) / 3 + 1;
var startQuarter = startdate.Value.Year * 4 + (startdate.Value.Month - 1) / 3 + 1;
var endQuarter = enddate.Value.UtcDateTime.Year * 4 + (enddate.Value.UtcDateTime.Month - 1) / 3 + 1;
var startQuarter = startdate.Value.UtcDateTime.Year * 4 + (startdate.Value.UtcDateTime.Month - 1) / 3 + 1;
return endQuarter - startQuarter;

case Engine.DatePart.Month:
return (enddate.Value.Year - startdate.Value.Year) * 12 + enddate.Value.Month - startdate.Value.Month;
return (enddate.Value.UtcDateTime.Year - startdate.Value.UtcDateTime.Year) * 12 + enddate.Value.UtcDateTime.Month - startdate.Value.UtcDateTime.Month;

case Engine.DatePart.DayOfYear:
case Engine.DatePart.Day:
case Engine.DatePart.WeekDay:
return (enddate.Value - startdate.Value).Days;
return (enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).Days;

case Engine.DatePart.Week:
case Engine.DatePart.ISOWeek:
return (enddate.Value - startdate.Value).Days / 7;
return (enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).Days / 7;

case Engine.DatePart.Hour:
return (int)(enddate.Value - startdate.Value).TotalHours;
return (int)(enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).TotalHours;

case Engine.DatePart.Minute:
return (int)(enddate.Value - startdate.Value).TotalMinutes;
return (int)(enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).TotalMinutes;

case Engine.DatePart.Second:
return (int)(enddate.Value - startdate.Value).TotalSeconds;
return (int)(enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).TotalSeconds;

case Engine.DatePart.Millisecond:
return (int)(enddate.Value - startdate.Value).TotalMilliseconds;
return (int)(enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).TotalMilliseconds;

case Engine.DatePart.Microsecond:
return (int)((enddate.Value - startdate.Value).Ticks / 10);
return (int)((enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).Ticks / 10);

case Engine.DatePart.Nanosecond:
return (int)((enddate.Value - startdate.Value).Ticks * 100);
return (int)((enddate.Value.UtcDateTime - startdate.Value.UtcDateTime).Ticks * 100);

default:
throw new QueryExecutionException(Sql4CdsError.InvalidOptionValue(new StringLiteral { Value = datepart.Value }, "datepart"));
Expand Down
8 changes: 4 additions & 4 deletions MarkMpn.Sql4Cds.Engine/SqlDateTypes.cs
Original file line number Diff line number Diff line change
Expand Up @@ -594,7 +594,7 @@ public override string ToString()
public struct SqlDateTimeOffset : INullable, IComparable
{
private readonly DateTimeOffset? _dt;
private static readonly DateTime _defaultDate = new DateTime(1900, 1, 1);
private static readonly DateTime _defaultDate = new DateTime(1900, 1, 1, 0, 0, 0, DateTimeKind.Utc);

public SqlDateTimeOffset(DateTimeOffset? dt)
{
Expand Down Expand Up @@ -700,15 +700,15 @@ public static implicit operator SqlDateTimeOffset(SqlDateTime dt)
if (dt.IsNull)
return Null;

return new SqlDateTimeOffset(dt.Value);
return new SqlDateTimeOffset(DateTime.SpecifyKind(dt.Value, DateTimeKind.Utc));
}

public static implicit operator SqlDateTimeOffset(SqlDate dt)
{
if (dt.IsNull)
return Null;

return new SqlDateTimeOffset(dt.Value);
return new SqlDateTimeOffset(DateTime.SpecifyKind(dt.Value, DateTimeKind.Utc));
}

public static implicit operator SqlDateTimeOffset(SqlTime dt)
Expand All @@ -724,7 +724,7 @@ public static implicit operator SqlDateTimeOffset(SqlDateTime2 dt)
if (dt.IsNull)
return Null;

return new SqlDateTimeOffset(dt.Value);
return new SqlDateTimeOffset(DateTime.SpecifyKind(dt.Value, DateTimeKind.Utc));
}

public static implicit operator SqlDateTimeOffset(SqlString str)
Expand Down
Binary file added MarkMpn.Sql4Cds.XTB/Images/LargeIcon_Smooth.png
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.

0 comments on commit 938d142

Please sign in to comment.