spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[DAYS360] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-04-03 01:28:29
stats
2 file(s) changed, 85 insertions(+), 1 deletions(-)
files
src/RawFormulas/Date.ts
tests/DateFormulasTest.ts
  1diff --git a/src/RawFormulas/Date.ts b/src/RawFormulas/Date.ts
  2index a2bb312..84f242e 100644
  3--- a/src/RawFormulas/Date.ts
  4+++ b/src/RawFormulas/Date.ts
  5@@ -137,9 +137,55 @@ var DAYS = function (...values) : number {
  6 };
  7 
  8 
  9-var DAYS360 = Formula["DAYS360"];
 10-var YEARFRAC = Formula["YEARFRAC"];
 11+/**
 12+ * Returns the difference between two days based on the 360 day year used in some financial interest calculations.
 13+ * @param values[0] start_date - The start date to consider in the calculation. Must be a reference to a cell containing
 14+ * a date, a function returning a date type, or a number.
 15+ * @param values[1] end_date - The end date to consider in the calculation. Must be a reference to a cell containing a
 16+ * date, a function returning a date type, or a number.
 17+ * @param values[2] method - [ OPTIONAL - 0 by default ] - An indicator of what day count method to use.
 18+ * 0 indicates the US method - Under the US method, if start_date is the last day of a month, the day of month of
 19+ * start_date is changed to 30 for the purposes of the calculation. Furthermore if end_date is the last day of a month
 20+ * and the day of the month of start_date is earlier than the 30th, end_date is changed to the first day of the month
 21+ * following end_date, otherwise the day of month of end_date is changed to 30.
 22+ * Any other value indicates the European method - Under the European method, any start_date or end_date that falls on
 23+ * the 31st of a month has its day of month changed to 30.
 24+ * @returns {number} of days between two dates
 25+ * @constructor
 26+ */
 27+var DAYS360 = function (...values) {
 28+  ArgsChecker.checkLengthWithin(values, 2, 3);
 29+  var start = TypeCaster.firstValueAsExcelDate(values[0], true).toMoment(); // tell firstValueAsExcelDate to coerce boolean
 30+  var end = TypeCaster.firstValueAsExcelDate(values[1], true).toMoment(); // tell firstValueAsExcelDate to coerce boolean
 31+  var methodToUse = false;
 32+  if (values.length === 3) {
 33+    methodToUse = TypeCaster.firstValueAsBoolean(values[2]);
 34+  }
 35+  var smd = 31;
 36+  var emd = 31;
 37+  var sd = start.date();
 38+  var ed = end.date();
 39+  if (methodToUse) {
 40+    sd = (sd === 31) ? 30 : sd;
 41+    ed = (ed === 31) ? 30 : ed;
 42+  }
 43+  else {
 44+    if (start.month() === 1) {
 45+      smd = start.daysInMonth();
 46+    }
 47+    if (end.month() === 1) {
 48+      emd = end.daysInMonth();
 49+    }
 50+    sd = (sd === smd) ? 30 : sd;
 51+    if (sd === 30 || sd === smd) {
 52+      ed = (ed === emd) ? 30 : ed;
 53+    }
 54+  }
 55+  return 360 * (end.year() - start.year()) + 30 * (end.month() - start.month()) + (ed - sd);
 56+};
 57 
 58+
 59+var YEARFRAC = Formula["YEARFRAC"];
 60 // Functions unimplemented.
 61 var DATEDIF;
 62 var HOUR;
 63diff --git a/tests/DateFormulasTest.ts b/tests/DateFormulasTest.ts
 64index d02ed43..6097617 100644
 65--- a/tests/DateFormulasTest.ts
 66+++ b/tests/DateFormulasTest.ts
 67@@ -1,5 +1,5 @@
 68 
 69-import { DATE, DATEVALUE, EDATE, EOMONTH, DAY, DAYS } from "../src/RawFormulas/RawFormulas"
 70+import { DATE, DATEVALUE, EDATE, EOMONTH, DAY, DAYS, DAYS360 } from "../src/RawFormulas/RawFormulas"
 71 import * as ERRORS from "../src/Errors"
 72 import {assertEquals} from "./utils/Asserts"
 73 import moment = require("moment");
 74@@ -19,6 +19,41 @@ function catchAndAssertEquals(toExecute, expected) {
 75   }
 76 }
 77 
 78+// Test DAYS360
 79+assertEquals(DAYS360(DATE(1992, 6, 24), DATE(1992, 6, 25)), 1);
 80+assertEquals(DAYS360(DATE(1992, 6, 25), DATE(1992, 6, 24)), -1);
 81+assertEquals(DAYS360(DATE(1992, 6, 25), DATE(1992, 6, 23)), -2);
 82+assertEquals(DAYS360(DATE(1992, 6, 24), DATE(1991, 6, 24)), -360);
 83+assertEquals(DAYS360(DATE(1993, 6, 24), DATE(1992, 6, 24)), -360);
 84+assertEquals(DAYS360(DATEVALUE("1993-6-24"), 1), -33653);
 85+assertEquals(DAYS360(DATEVALUE("1993-6-24"), true), -33653);
 86+assertEquals(DAYS360(DATEVALUE("1993-6-24"), 0), -33654);
 87+assertEquals(DAYS360(DATEVALUE("1993-6-24"), false), -33654);
 88+assertEquals(DAYS360("2191-6-24", "1992-6-24"), -71640);
 89+assertEquals(DAYS360("2191-6-24", "1992-6-24", true), -71640);
 90+assertEquals(DAYS360(1, 390, 1), 384);
 91+assertEquals(DAYS360(1, 390), 384);
 92+assertEquals(DAYS360(33779, 33780), 1);
 93+assertEquals(DAYS360([1, "str"], [390, "str"]), 384);
 94+catchAndAssertEquals(function() {
 95+  DAYS360();
 96+}, ERRORS.NA_ERROR);
 97+catchAndAssertEquals(function() {
 98+  DAYS360(100);
 99+}, ERRORS.NA_ERROR);
100+catchAndAssertEquals(function() {
101+  DAYS360(100, 200, true, "str");
102+}, ERRORS.NA_ERROR);
103+catchAndAssertEquals(function() {
104+  DAYS360("str", 100);
105+}, ERRORS.VALUE_ERROR);
106+catchAndAssertEquals(function() {
107+  DAYS360("false", "true");
108+}, ERRORS.VALUE_ERROR);
109+catchAndAssertEquals(function() {
110+  DAYS360([[], 100], 22);
111+}, ERRORS.REF_ERROR);
112+
113 
114 // Test DAYS
115 assertEquals(DAYS(DATE(1992, 6, 24), DATE(1992, 6, 25)), -1);