spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[NETWORKDAYS.INTL, README.md] formula added and tested, added TODOs
author
Ben Vogt <[email protected]>
date
2017-04-26 00:17:02
stats
4 file(s) changed, 170 insertions(+), 5 deletions(-)
files
README.md
src/RawFormulas/Date.ts
src/RawFormulas/RawFormulas.ts
tests/DateFormulasTest.ts
  1diff --git a/README.md b/README.md
  2index 502e758..4164f58 100644
  3--- a/README.md
  4+++ b/README.md
  5@@ -44,6 +44,9 @@ Right now we're just using the number of days since 1900, but we should check th
  6 
  7 ### Verify that all N-times ({2,9}) are correct, and we're not parsing numbers too big.
  8 
  9+### Scrape jsdocs from functions, put in simple index.html, doc.md files to serve up simple documentation
 10+
 11+### Numbers with commas in them should still parse to numbers.
 12 
 13 
 14 ## Testing Guidelines
 15diff --git a/src/RawFormulas/Date.ts b/src/RawFormulas/Date.ts
 16index caf7709..194e6cf 100644
 17--- a/src/RawFormulas/Date.ts
 18+++ b/src/RawFormulas/Date.ts
 19@@ -632,7 +632,7 @@ var NETWORKDAYS = function (...values) : number {
 20       } else if (typeof holidayDateValue === "number") {
 21         holidays.push(holidayDateValue);
 22       } else {
 23-        throw new ValueError("NETWORKDAYS expects number values. But '"+holidayDateValue+"' is a " +
 24+        throw new ValueError("NETWORKDAYS expects number values. But '" + holidayDateValue + "' is a " +
 25             (typeof holidayDateValue) + " and cannot be coerced to a number.")
 26       }
 27     }
 28@@ -666,12 +666,110 @@ var NETWORKDAYS = function (...values) : number {
 29   return networkDays;
 30 };
 31 
 32+/**
 33+ * Returns the number of networking days between two provided days excluding specified weekend days and holidays.
 34+ * @param values[0] start_date - The start date of the period from which to calculate the number of net working days.
 35+ * @param values[1] end_date - The end date of the period from which to calculate the number of net working days.
 36+ * @param values[2] weekend - [ OPTIONAL - 1 by default ] - A number or string representing which days of the week are
 37+ * considered weekends. String method: weekends can be specified using seven 0’s and 1’s, where the first number in the
 38+ * set represents Monday and the last number is for Sunday. A zero means that the day is a work day, a 1 means that the
 39+ * day is a weekend. For example, “0000011” would mean Saturday and Sunday are weekends. Number method: instead of using
 40+ * the string method above, a single number can be used. 1 = Saturday/Sunday are weekends, 2 = Sunday/Monday, and this
 41+ * pattern repeats until 7 = Friday/Saturday. 11 = Sunday is the only weekend, 12 = Monday is the only weekend, and this
 42+ * pattern repeats until 17 = Saturday is the only weekend.
 43+ * @param values[3] holidays - [ OPTIONAL ] - A range or array constant containing the dates to consider as holidays.
 44+ * The values provided within an array for holidays must be date serial number values, as returned by N or date values,
 45+ * as returned by DATE, DATEVALUE or TO_DATE. Values specified by a range should be standard date values or date serial
 46+ * numbers.
 47+ * @returns {number} of networking days between two provided days
 48+ * @constructor
 49+ */
 50+var NETWORKDAYS$INTL = function (...values) : number {
 51+  ArgsChecker.checkLengthWithin(values, 2, 4);
 52+  var start = TypeCaster.firstValueAsExcelDate(values[0], true);
 53+  var end = TypeCaster.firstValueAsExcelDate(values[1], true);
 54+  var weekendDays = [];
 55+  if (values.length >= 3) {
 56+    var weekend = TypeCaster.firstValue(values[2]);
 57+    if (typeof weekend === "string") {
 58+      if (!/^[0-1]{6,}$/.test(weekend)) {
 59+        // TODO: throw error, it doesn't match
 60+      }
 61+      var ws = weekend.split("");
 62+      for (var i = 0; i < ws.length; i++) {
 63+        if (ws[i] === "1") {
 64+          weekendDays.push(i === 6 ? 0 : i + 1);
 65+        }
 66+      }
 67+    } else if (typeof weekend === "number") {
 68+      switch (weekend) {
 69+        case 1:
 70+          weekendDays = [0, 6];
 71+          break;
 72+        case 2 || 3 || 4 || 5 || 6 || 7:
 73+          weekendDays = [weekend, weekend - 1];
 74+          break;
 75+        case 11 || 12 || 13 || 14 || 15 || 16 || 17:
 76+          weekendDays = [weekend - 10];
 77+          break;
 78+        default:
 79+          // TODO throw error, not a recognized number.
 80+          break;
 81+      }
 82+    } else {
 83+      // TODO: Throw error.
 84+    }
 85+  } else {
 86+    weekendDays = [1, 6];
 87+  }
 88+  var hasHolidays = values.length === 4;
 89+  var holidays = [];
 90+  if (hasHolidays) {
 91+    if (values[3].length === 0) {
 92+      throw new RefError("Reference does not exist.");
 93+    }
 94+    for (var holidayDateValue of values[3]) {
 95+      if (holidayDateValue instanceof ExcelDate) {
 96+        holidays.push(holidayDateValue.toNumber());
 97+      } else if (typeof holidayDateValue === "number") {
 98+        holidays.push(holidayDateValue);
 99+      } else {
100+        throw new ValueError("NETWORKDAYS.INTL expects number values. But '" + holidayDateValue + "' is a " +
101+          (typeof holidayDateValue) + " and cannot be coerced to a number.")
102+      }
103+    }
104+  }
105+  // Handle cases in which the start date is not before the end date.
106+  var didSwap = start.toNumber() > end.toNumber();
107+  if (didSwap) {
108+    var swap = end;
109+    end = start;
110+    start = swap;
111+  }
112 
113-// Functions unimplemented.
114-var __COMPLEX_ITL = {
115-  "NETWORKDAYS.ITL": function () {},
116-  "WORKDAY.INTL": function () {}
117+  var c = moment.utc(start.toMoment());
118+  var days = end.toNumber() - start.toNumber() + 1;
119+  var networkDays = days;
120+  var j = 0;
121+  while (j < days) {
122+    if (weekendDays.indexOf(c.day()) >= 0) {
123+      networkDays--;
124+    } else if (hasHolidays && holidays.indexOf(new ExcelDate(c).toNumber()) > -1) {
125+      networkDays--;
126+    }
127+    c.add(1, 'days');
128+    j++;
129+  }
130+  // If the we swapped the start and end date, the result should be a negative number of network days.
131+  if (didSwap) {
132+    return networkDays * -1;
133+  }
134+  return networkDays;
135 };
136+
137+
138+// Functions unimplemented.
139+var WORKDAY$INTL;
140 var NOW;
141 var TIME;
142 var TODAY;
143@@ -695,5 +793,6 @@ export {
144   HOUR,
145   MINUTE,
146   SECOND,
147-  NETWORKDAYS
148+  NETWORKDAYS,
149+  NETWORKDAYS$INTL
150 }
151\ No newline at end of file
152diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
153index 6028d86..71e151e 100644
154--- a/src/RawFormulas/RawFormulas.ts
155+++ b/src/RawFormulas/RawFormulas.ts
156@@ -126,7 +126,8 @@ import {
157   HOUR,
158   MINUTE,
159   SECOND,
160-  NETWORKDAYS
161+  NETWORKDAYS,
162+  NETWORKDAYS$INTL
163 } from "./Date"
164 
165 var ACCRINT = Formula["ACCRINT"];
166@@ -256,5 +257,6 @@ export {
167   HOUR,
168   MINUTE,
169   SECOND,
170-  NETWORKDAYS
171+  NETWORKDAYS,
172+  NETWORKDAYS$INTL
173 }
174\ No newline at end of file
175diff --git a/tests/DateFormulasTest.ts b/tests/DateFormulasTest.ts
176index 639d85a..8191ba5 100644
177--- a/tests/DateFormulasTest.ts
178+++ b/tests/DateFormulasTest.ts
179@@ -17,7 +17,8 @@ import {
180   HOUR,
181   MINUTE,
182   SECOND,
183-  NETWORKDAYS
184+  NETWORKDAYS,
185+  NETWORKDAYS$INTL
186 } from "../src/RawFormulas/RawFormulas"
187 import * as ERRORS from "../src/Errors"
188 import {assertEquals} from "./utils/Asserts"
189@@ -39,6 +40,58 @@ function catchAndAssertEquals(toExecute, expected) {
190   }
191 }
192 
193+// Test NETWORKDAYS$INTL
194+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-30"), 22);
195+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-1"), 263);
196+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-4"), 264);
197+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-5"), 265);
198+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-6"), 266);
199+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-7"), 267);
200+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-8"), 268);
201+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-9"), 268);
202+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-30", "0000011"), 22);
203+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-1", "0000011"), 263);
204+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-4", "0000011"), 264);
205+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-5", "0000011"), 265);
206+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-6", "0000011"), 266);
207+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-7", "0000011"), 267);
208+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-8", "0000011"), 268);
209+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-9", "0000011"), 268);
210+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-30", 1), 22);
211+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-1", 1), 263);
212+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-4", 1), 264);
213+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-5", 1), 265);
214+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-6", 1), 266);
215+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-7", 1), 267);
216+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-8", 1), 268);
217+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-1-9", 1), 268);
218+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-6", "1110011"), 2);
219+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-14", "1110011"), 4);
220+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-30", "1110011"), 9);
221+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-1-30", "0001110"), 17);
222+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-2-22", "0001110"), 29);
223+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1993-2-22", "0001110"), 239);
224+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-2-22", "0000110"), 37);
225+assertEquals(NETWORKDAYS$INTL("1992-1-1", "1992-2-22", 1, [DATE(1992, 1, 10), DATE(1992, 1, 11), DATE(1992, 1, 12), DATE(1992, 1, 13), DATE(1992, 1, 14)]), 35);
226+assertEquals(NETWORKDAYS$INTL(["1992-1-1"], ["1992-1-30"], ["0000011"]), 22);
227+catchAndAssertEquals(function() {
228+  NETWORKDAYS$INTL(12, 12, [12], false, 1);
229+}, ERRORS.NA_ERROR);
230+catchAndAssertEquals(function() {
231+  NETWORKDAYS$INTL(12);
232+}, ERRORS.NA_ERROR);
233+catchAndAssertEquals(function() {
234+  NETWORKDAYS$INTL("1992-1-1", "str");
235+}, ERRORS.VALUE_ERROR);
236+catchAndAssertEquals(function() {
237+  NETWORKDAYS$INTL(12, 12, 1, ["1992-11-1"]);
238+}, ERRORS.VALUE_ERROR);
239+catchAndAssertEquals(function() {
240+  NETWORKDAYS$INTL("1992-1-1", "1992-1-1", []);
241+}, ERRORS.REF_ERROR);
242+
243+
244+
245 // Test NETWORKDAYS
246 assertEquals(NETWORKDAYS("1992-1-1", "1992-1-30"), 22);
247 assertEquals(NETWORKDAYS("1992-1-1", "1993-1-1"), 263);