Skip to content

Commit

Permalink
Implement DATEDIF function (#1551)
Browse files Browse the repository at this point in the history
* Implement DATEDIF function.

https://support.microsoft.com/en-us/office/datedif-function-25dba1a4-2812-480b-84dd-8b32a451b35c

* Refactor DATEDIF

Co-authored-by: Aleksei <pankraty@gmail.com>

Co-authored-by: Artem Smolyanchenko <saa9@europlan.ru>
Co-authored-by: Francois Botha <igitur@gmail.com>
Co-authored-by: Aleksei <pankraty@gmail.com>
  • Loading branch information
4 people committed Dec 16, 2020
1 parent bed9238 commit 20c6acf
Show file tree
Hide file tree
Showing 2 changed files with 80 additions and 15 deletions.
27 changes: 27 additions & 0 deletions ClosedXML/Excel/CalcEngine/Functions/DateAndTime.cs
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@
using ClosedXML.Excel.CalcEngine.Exceptions;
using System;
using System.Collections.Generic;
using System.Globalization;
Expand All @@ -10,6 +11,7 @@ internal static class DateAndTime
public static void Register(CalcEngine ce)
{
ce.RegisterFunction("DATE", 3, Date); // Returns the serial number of a particular date
ce.RegisterFunction("DATEDIF", 3, Datedif); // Calculates the number of days, months, or years between two dates
ce.RegisterFunction("DATEVALUE", 1, Datevalue); // Converts a date in the form of text to a serial number
ce.RegisterFunction("DAY", 1, Day); // Converts a serial number to a day of the month
ce.RegisterFunction("DAYS", 2, Days); // Returns the number of days between two dates.
Expand Down Expand Up @@ -113,6 +115,31 @@ private static object Date(List<Expression> p)
return (int)Math.Floor(new DateTime(year, month, day).AddDays(daysAdjustment).ToOADate());
}

private static object Datedif(List<Expression> p)
{
DateTime startDate = p[0];
DateTime endDate = p[1];
string unit = p[2];

if (startDate > endDate)
throw new NumberException("The start date is greater than the end date");

return (unit.ToUpper()) switch
{
"Y" => endDate.Year - startDate.Year - (new DateTime(startDate.Year, endDate.Month, endDate.Day) < startDate ? 1 : 0),
"M" => Math.Truncate((endDate.Year - startDate.Year) * 12d + endDate.Month - startDate.Month - (endDate.Day < startDate.Day ? 1 : 0)),
"D" => Math.Truncate(endDate.Date.Subtract(startDate.Date).TotalDays),

// Microsoft discouranges the use of the MD parameter
// https://support.microsoft.com/en-us/office/datedif-function-25dba1a4-2812-480b-84dd-8b32a451b35c
"MD" => (endDate.Day - startDate.Day + DateTime.DaysInMonth(startDate.Year, startDate.Month)) % DateTime.DaysInMonth(startDate.Year, startDate.Month),

"YM" => (endDate.Month - startDate.Month + 12) % 12 - (endDate.Day < startDate.Day ? 1 : 0),
"YD" => Math.Truncate(new DateTime(startDate.Year + (new DateTime(startDate.Year, endDate.Month, endDate.Day) < startDate ? 1 : 0), endDate.Month, endDate.Day).Subtract(startDate).TotalDays),
_ => throw new NumberException(),
};
}

private static object Datevalue(List<Expression> p)
{
var date = (string)p[0];
Expand Down
68 changes: 53 additions & 15 deletions ClosedXML_Tests/Excel/CalcEngine/DateAndTimeTests.cs
Original file line number Diff line number Diff line change
@@ -1,8 +1,9 @@
using ClosedXML.Excel;
using ClosedXML.Excel.CalcEngine.Exceptions;
using NUnit.Framework;
using System;
using System.Globalization;
using System.Threading;
using ClosedXML.Excel;
using NUnit.Framework;

namespace ClosedXML_Tests.Excel.DataValidations
{
Expand Down Expand Up @@ -42,6 +43,44 @@ public void Date()
Assert.AreEqual(39752, actual);
}

[TestCase("1/1/2006", "12/12/2010", "Y", ExpectedResult = 4)]
[TestCase("1/1/2006", "12/12/2010", "M", ExpectedResult = 59)]
[TestCase("1/1/2006", "12/12/2010", "D", ExpectedResult = 1806)]
[TestCase("1/1/2006", "12/12/2010", "MD", ExpectedResult = 11)]
[TestCase("1/1/2006", "12/12/2010", "YM", ExpectedResult = 11)]
[TestCase("1/1/2006", "12/12/2010", "YD", ExpectedResult = 345)]
[TestCase(38718, 40524, "Y", ExpectedResult = 4)]
[TestCase(38718, 40524, "M", ExpectedResult = 59)]
[TestCase(38718, 40524, "D", ExpectedResult = 1806)]
[TestCase(38718, 40524, "MD", ExpectedResult = 11)]
[TestCase(38718, 40524, "YM", ExpectedResult = 11)]
[TestCase(38718, 40524, "YD", ExpectedResult = 345)]
[TestCase("2001-12-31", "2002-4-15", "YM", ExpectedResult = 3)]
[TestCase("2001-12-10", "2002-4-15", "YM", ExpectedResult = 4)]
[TestCase("2001-12-15", "2002-4-15", "YM", ExpectedResult = 4)]
[TestCase("2001-12-31", "2002-4-15", "YD", ExpectedResult = 105)]
[TestCase("2001-12-31", "2003-4-15", "YD", ExpectedResult = 105)]
[TestCase("2002-01-31", "2002-4-15", "YD", ExpectedResult = 74)]
[TestCase("2001-12-02", "2001-12-15", "Y", ExpectedResult = 0)]
[TestCase("2001-12-02", "2002-12-02", "Y", ExpectedResult = 1)]
[TestCase("2006-01-15", "2006-03-14", "M", ExpectedResult = 1)]
[TestCase("2020-11-22", "2020-11-23 9:00", "D", ExpectedResult = 1)]
public double Datedif(object startDate, object endDate, string unit)
{
if (startDate is string s1) startDate = $"\"{s1}\"";
if (endDate is string s2) endDate = $"\"{s2}\"";
return (double)XLWorkbook.EvaluateExpr($"DATEDIF({startDate}, {endDate}, \"{unit}\")");
}

[TestCase("\"1/1/2010\"", "\"12/12/2006\"", "Y")]
[TestCase(40524, 38718, "Y")]
[TestCase("\"1/1/2006\"", "\"12/12/2010\"", "N")]
[TestCase(38718, 40524, "N")]
public void DatedifExceptions(object startDate, object endDate, string unit)
{
Assert.Throws<NumberException>(() => XLWorkbook.EvaluateExpr($"DATEDIF({startDate}, {endDate}, \"{unit}\")"));
}

[Test]
public void Datevalue()
{
Expand Down Expand Up @@ -241,14 +280,14 @@ public void Time()
public void TimeValue1()
{
Object actual = XLWorkbook.EvaluateExpr("TimeValue(\"2:24 AM\")");
Assert.IsTrue(XLHelper.AreEqual(0.1, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.1, (double)actual));
}

[Test]
public void TimeValue2()
{
Object actual = XLWorkbook.EvaluateExpr("TimeValue(\"22-Aug-2008 6:35 AM\")");
Assert.IsTrue(XLHelper.AreEqual(0.27430555555555558, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.27430555555555558, (double)actual));
}

[Test]
Expand Down Expand Up @@ -428,7 +467,6 @@ public void Workdays_MultipleHolidaysGiven()
Assert.AreEqual(new DateTime(2009, 5, 5), actual);
}


[Test]
public void Workdays_NoHolidaysGiven()
{
Expand Down Expand Up @@ -457,70 +495,70 @@ public void Year()
public void Yearfrac_1_base0()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2008\",0)");
Assert.IsTrue(XLHelper.AreEqual(0.25, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.25, (double)actual));
}

[Test]
public void Yearfrac_1_base1()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2008\",1)");
Assert.IsTrue(XLHelper.AreEqual(0.24590163934426229, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.24590163934426229, (double)actual));
}

[Test]
public void Yearfrac_1_base2()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2008\",2)");
Assert.IsTrue(XLHelper.AreEqual(0.25, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.25, (double)actual));
}

[Test]
public void Yearfrac_1_base3()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2008\",3)");
Assert.IsTrue(XLHelper.AreEqual(0.24657534246575341, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.24657534246575341, (double)actual));
}

[Test]
public void Yearfrac_1_base4()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2008\",4)");
Assert.IsTrue(XLHelper.AreEqual(0.24722222222222223, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(0.24722222222222223, (double)actual));
}

[Test]
public void Yearfrac_2_base0()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2013\",0)");
Assert.IsTrue(XLHelper.AreEqual(5.25, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(5.25, (double)actual));
}

[Test]
public void Yearfrac_2_base1()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2013\",1)");
Assert.IsTrue(XLHelper.AreEqual(5.24452554744526, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(5.24452554744526, (double)actual));
}

[Test]
public void Yearfrac_2_base2()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2013\",2)");
Assert.IsTrue(XLHelper.AreEqual(5.32222222222222, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(5.32222222222222, (double)actual));
}

[Test]
public void Yearfrac_2_base3()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2013\",3)");
Assert.IsTrue(XLHelper.AreEqual(5.24931506849315, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(5.24931506849315, (double)actual));
}

[Test]
public void Yearfrac_2_base4()
{
Object actual = XLWorkbook.EvaluateExpr("Yearfrac(\"1/1/2008\", \"3/31/2013\",4)");
Assert.IsTrue(XLHelper.AreEqual(5.24722222222222, (double) actual));
Assert.IsTrue(XLHelper.AreEqual(5.24722222222222, (double)actual));
}
}
}

0 comments on commit 20c6acf

Please sign in to comment.