spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[NETWORKDAYS] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-04-23 19:28:35
stats
3 file(s) changed, 136 insertions(+), 6 deletions(-)
files
src/RawFormulas/Date.ts
src/RawFormulas/RawFormulas.ts
tests/DateFormulasTest.ts
  1diff --git a/src/RawFormulas/Date.ts b/src/RawFormulas/Date.ts
  2index ac577e8..caf7709 100644
  3--- a/src/RawFormulas/Date.ts
  4+++ b/src/RawFormulas/Date.ts
  5@@ -1,12 +1,13 @@
  6 /// <reference path="../../node_modules/moment/moment.d.ts"/>
  7 import * as moment from "moment";
  8-import * as Formula from "formulajs"
  9 import {
 10   ArgsChecker,
 11   TypeCaster
 12 } from "./Utils";
 13 import {
 14-  NumError, ValueError
 15+  NumError,
 16+  ValueError,
 17+  RefError
 18 } from "../Errors";
 19 import {
 20   ExcelDate,
 21@@ -604,8 +605,69 @@ var SECOND = function (...values) : number {
 22 };
 23 
 24 
 25+/**
 26+ * Returns the number of net working days between two provided days.
 27+ * @param values[0] start_date - The start date of the period from which to calculate the number of net working days.
 28+ * @param values[1] end_date - The end date of the period from which to calculate the number of net working days.
 29+ * @param values[1] holidays - [ OPTIONAL ] - A range or array constant containing the date serial numbers to consider
 30+ * holidays. The values provided within an array for holidays must be date serial number values, as returned by N or
 31+ * date values, as returned by DATE, DATEVALUE or TO_DATE. Values specified by a range should be standard date values or
 32+ * date serial numbers.
 33+ * @returns {number} the number of net working days between two provided dates.
 34+ * @constructor
 35+ */
 36+var NETWORKDAYS = function (...values) : number {
 37+  ArgsChecker.checkLengthWithin(values, 2, 3);
 38+  var start = TypeCaster.firstValueAsExcelDate(values[0], true);
 39+  var end = TypeCaster.firstValueAsExcelDate(values[1], true);
 40+  var hasHolidays = values.length === 3;
 41+  var holidays = [];
 42+  if (hasHolidays) {
 43+    if (values[2].length === 0) {
 44+      throw new RefError("Reference does not exist.");
 45+    }
 46+    for (var holidayDateValue of values[2]) {
 47+      if (holidayDateValue instanceof ExcelDate) {
 48+        holidays.push(holidayDateValue.toNumber());
 49+      } else if (typeof holidayDateValue === "number") {
 50+        holidays.push(holidayDateValue);
 51+      } else {
 52+        throw new ValueError("NETWORKDAYS expects number values. But '"+holidayDateValue+"' is a " +
 53+            (typeof holidayDateValue) + " and cannot be coerced to a number.")
 54+      }
 55+    }
 56+  }
 57+  // Handle cases in which the start date is not before the end date.
 58+  var didSwap = start.toNumber() > end.toNumber();
 59+  if (didSwap) {
 60+    var swap = end;
 61+    end = start;
 62+    start = swap;
 63+  }
 64+
 65+  var c = moment.utc(start.toMoment());
 66+  var weekendDays = [6, 0]; // Default weekend_days.
 67+  var days = end.toNumber() - start.toNumber() + 1;
 68+  var networkDays = days;
 69+  var j = 0;
 70+  while (j < days) {
 71+    if (weekendDays.indexOf(c.day()) >= 0) {
 72+      networkDays--;
 73+    } else if (hasHolidays && holidays.indexOf(new ExcelDate(c).toNumber()) > -1) {
 74+      networkDays--;
 75+    }
 76+    c.add(1, 'days');
 77+    j++;
 78+  }
 79+  // If the we swapped the start and end date, the result should be a negative number of network days.
 80+  if (didSwap) {
 81+    return networkDays * -1;
 82+  }
 83+  return networkDays;
 84+};
 85+
 86+
 87 // Functions unimplemented.
 88-var NETWORKDAYS;
 89 var __COMPLEX_ITL = {
 90   "NETWORKDAYS.ITL": function () {},
 91   "WORKDAY.INTL": function () {}
 92@@ -632,5 +694,6 @@ export {
 93   TIMEVALUE,
 94   HOUR,
 95   MINUTE,
 96-  SECOND
 97+  SECOND,
 98+  NETWORKDAYS
 99 }
100\ No newline at end of file
101diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
102index ba1b430..6028d86 100644
103--- a/src/RawFormulas/RawFormulas.ts
104+++ b/src/RawFormulas/RawFormulas.ts
105@@ -125,7 +125,8 @@ import {
106   TIMEVALUE,
107   HOUR,
108   MINUTE,
109-  SECOND
110+  SECOND,
111+  NETWORKDAYS
112 } from "./Date"
113 
114 var ACCRINT = Formula["ACCRINT"];
115@@ -254,5 +255,6 @@ export {
116   TIMEVALUE,
117   HOUR,
118   MINUTE,
119-  SECOND
120+  SECOND,
121+  NETWORKDAYS
122 }
123\ No newline at end of file
124diff --git a/tests/DateFormulasTest.ts b/tests/DateFormulasTest.ts
125index 7db05cc..639d85a 100644
126--- a/tests/DateFormulasTest.ts
127+++ b/tests/DateFormulasTest.ts
128@@ -16,7 +16,8 @@ import {
129   TIMEVALUE,
130   HOUR,
131   MINUTE,
132-  SECOND
133+  SECOND,
134+  NETWORKDAYS
135 } from "../src/RawFormulas/RawFormulas"
136 import * as ERRORS from "../src/Errors"
137 import {assertEquals} from "./utils/Asserts"
138@@ -28,8 +29,9 @@ function catchAndAssertEquals(toExecute, expected) {
139     toExecute();
140     toThrow = true;
141   } catch (actualError) {
142-    if (actualError.name != expected) {
143-      console.log(expected, "not equal to", actualError.name);
144+    if (actualError.name !== expected) {
145+      console.log("expected:", expected, " actual:", actualError.name);
146+      console.trace();
147     }
148   }
149   if (toThrow) {
150@@ -37,6 +39,55 @@ function catchAndAssertEquals(toExecute, expected) {
151   }
152 }
153 
154+// Test NETWORKDAYS
155+assertEquals(NETWORKDAYS("1992-1-1", "1992-1-30"), 22);
156+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-1"), 263);
157+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-4"), 264);
158+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-5"), 265);
159+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-6"), 266);
160+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-7"), 267);
161+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-8"), 268);
162+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-9"), 268);
163+assertEquals(NETWORKDAYS("1992-1-1", "2000-4-24"), 2169);
164+assertEquals(NETWORKDAYS("1992-1-1", false), -24003);
165+assertEquals(NETWORKDAYS("2020-12-12", 0), -31555);
166+assertEquals(NETWORKDAYS(12, 1423), 1008);
167+assertEquals(NETWORKDAYS(12, 12), 1);
168+assertEquals(NETWORKDAYS(DATE(1900, 1, 11), 12), 1);
169+assertEquals(NETWORKDAYS(DATE(1998, 1, 1), DATE(1999, 1, 22)), 277);
170+// Single holiday test
171+assertEquals(NETWORKDAYS("1992-1-1", "1992-1-30", [DATEVALUE("1992-1-22")]), 21);
172+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-1", [DATEVALUE("1992-6-19")]), 262);
173+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-4", [DATEVALUE("1992-6-19")]), 263);
174+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-5", [DATEVALUE("1992-6-19")]), 264);
175+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-6", [DATEVALUE("1992-6-19")]), 265);
176+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-7", [DATEVALUE("1992-6-19"), DATEVALUE("1992-6-18")]), 265);
177+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-8", [DATEVALUE("1992-6-19")]), 267);
178+assertEquals(NETWORKDAYS("1992-1-1", "1993-1-9", [DATEVALUE("1992-6-19")]), 267);
179+assertEquals(NETWORKDAYS("1992-1-1", "2000-4-24", [DATEVALUE("1992-6-19")]), 2168);
180+assertEquals(NETWORKDAYS("1992-1-1", false, [DATEVALUE("1991-6-19")]), -24002);
181+assertEquals(NETWORKDAYS("2020-12-12", 0, [DATEVALUE("1992-6-19")]), -31554);
182+assertEquals(NETWORKDAYS(12, 1423, [22]), 1008);// weekend and holdiay overlapping
183+assertEquals(NETWORKDAYS(12, 1423, [20]), 1007);
184+assertEquals(NETWORKDAYS(12, 12, [12]), 0);
185+assertEquals(NETWORKDAYS(DATE(1998, 1, 1), DATE(1999, 1, 22), [DATE(1999, 1, 20)]), 276);
186+catchAndAssertEquals(function() {
187+  NETWORKDAYS(12, 12, [12], false);
188+}, ERRORS.NA_ERROR);
189+catchAndAssertEquals(function() {
190+  NETWORKDAYS(12);
191+}, ERRORS.NA_ERROR);
192+catchAndAssertEquals(function() {
193+  NETWORKDAYS("1992-1-1", "str");
194+}, ERRORS.VALUE_ERROR);
195+catchAndAssertEquals(function() {
196+  NETWORKDAYS(12, 12, ["1992-11-1"]);
197+}, ERRORS.VALUE_ERROR);
198+catchAndAssertEquals(function() {
199+  NETWORKDAYS("1992-1-1", "1992-1-1", []);
200+}, ERRORS.REF_ERROR);
201+
202+
203 
204 // Test SECOND
205 assertEquals(SECOND("8:10"), 0);