spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[WORKDAY.INTL] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-04-29 16:36:57
stats
4 file(s) changed, 174 insertions(+), 10 deletions(-)
files
src/RawFormulas/Date.ts
src/RawFormulas/RawFormulas.ts
tests/DateFormulasTest.ts
tests/utils/Asserts.ts
  1diff --git a/src/RawFormulas/Date.ts b/src/RawFormulas/Date.ts
  2index a4aaf4f..c681308 100644
  3--- a/src/RawFormulas/Date.ts
  4+++ b/src/RawFormulas/Date.ts
  5@@ -710,15 +710,26 @@ var NETWORKDAYS$INTL = function (...values) : number {
  6         case 1:
  7           weekendDays = [0, 6];
  8           break;
  9-        case 2 || 3 || 4 || 5 || 6 || 7:
 10+        case 2:
 11+        case 3:
 12+        case 4:
 13+        case 5:
 14+        case 6:
 15+        case 7:
 16           weekendDays = [weekend, weekend - 1];
 17           break;
 18-        case 11 || 12 || 13 || 14 || 15 || 16 || 17:
 19+        case 11:
 20+        case 12:
 21+        case 13:
 22+        case 14:
 23+        case 15:
 24+        case 16:
 25+        case 17:
 26           weekendDays = [weekend - 10];
 27           break;
 28         default:
 29           throw new NumError("Function NETWORKDAYS.INTL parameter 3 requires a number in the range 1-7 or 11-17. "
 30-              + "Actual number is " + weekend + ".");
 31+            + "Actual number is " + weekend + ".");
 32       }
 33     } else {
 34       throw new ValueError("Function NETWORKDAYS.INTL parameter 4 expects number values. But '" + weekend
 35@@ -726,7 +737,7 @@ var NETWORKDAYS$INTL = function (...values) : number {
 36     }
 37   } else {
 38     // TODO: This had the wrong number of default weekend values and was still passing. Add a test that fails with
 39-    // TODO:     weekendDays = [1, 6] but not with [2, 6].
 40+    // TODO:     weekendDays = [1, 6] but not with [0, 6].
 41     weekendDays = [0, 6];
 42   }
 43   var hasHolidays = values.length === 4;
 44@@ -855,12 +866,12 @@ var WORKDAY = function (...values) {
 45     }
 46   }
 47 
 48-  var weekend_days = [0, 6];
 49+  var weekendDays = [0, 6];
 50   var cd = moment.utc(start.toMoment());
 51   var j = 0;
 52   while (j < days) {
 53     cd.add(1, 'days');
 54-    if (weekend_days.indexOf(cd.day()) < 0 && holidays.indexOf(new ExcelDate(cd).toNumber()) < 0) {
 55+    if (weekendDays.indexOf(cd.day()) < 0 && holidays.indexOf(new ExcelDate(cd).toNumber()) < 0) {
 56       j++;
 57     }
 58   }
 59@@ -868,9 +879,103 @@ var WORKDAY = function (...values) {
 60 };
 61 
 62 
 63-
 64-// Functions unimplemented.
 65-var WORKDAY$INTL;
 66+/**
 67+ * Calculates the date after a specified number of workdays excluding specified weekend days and holidays.
 68+ * @param values[0] start_date - The date from which to begin counting.
 69+ * @param values[1] num_days - The number of working days to advance from start_date. If negative, counts backwards.
 70+ * @param values[2] weekend - [ OPTIONAL - 1 by default ] - A number or string representing which days of the week are
 71+ * considered weekends. String method: weekends can be specified using seven 0’s and 1’s, where the first number in the
 72+ * 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
 73+ * day is a weekend. For example, “0000011” would mean Saturday and Sunday are weekends. Number method: instead of using
 74+ * the string method above, a single number can be used. 1 = Saturday/Sunday are weekends, 2 = Sunday/Monday, and this
 75+ * pattern repeats until 7 = Friday/Saturday. 11 = Sunday is the only weekend, 12 = Monday is the only weekend, and this
 76+ * pattern repeats until 17 = Saturday is the only weekend.
 77+ * @param values[3] holidays - [ OPTIONAL ] - A range or array constant containing the dates to consider holidays.
 78+ * @returns {ExcelDate}
 79+ * @constructor
 80+ */
 81+var WORKDAY$INTL = function (...values) {
 82+  ArgsChecker.checkLengthWithin(values, 2, 3);
 83+  var start = TypeCaster.firstValueAsExcelDate(values[0], true);
 84+  var days = TypeCaster.firstValueAsNumber(values[1]);
 85+  var weekendDays = [];
 86+  if (values.length >= 3) {
 87+    var weekend = TypeCaster.firstValue(values[2]);
 88+    if (typeof weekend === "string") {
 89+      if (!/^[0-1]{6,}$/.test(weekend)) {
 90+        throw new NumError("Function WORKDAY.INTL parameter 3 requires a number in the format '0000011'. "
 91+          + "Actual value is '" + weekend + "'");
 92+      }
 93+      var ws = weekend.split("");
 94+      for (var i = 0; i < ws.length; i++) {
 95+        if (ws[i] === "1") {
 96+          weekendDays.push(i === 6 ? 0 : i + 1);
 97+        }
 98+      }
 99+    } else if (typeof weekend === "number") {
100+      switch (weekend) {
101+        case 1:
102+          weekendDays = [0, 6];
103+          break;
104+        case 2:
105+        case 3:
106+        case 4:
107+        case 5:
108+        case 6:
109+        case 7:
110+          weekendDays = [weekend, weekend - 1];
111+          break;
112+        case 11:
113+        case 12:
114+        case 13:
115+        case 14:
116+        case 15:
117+        case 16:
118+        case 17:
119+          weekendDays = [weekend - 10];
120+          break;
121+        default:
122+          throw new NumError("Function WORKDAY.INTL parameter 3 requires a number in the range 1-7 or 11-17. "
123+            + "Actual number is " + weekend + ".");
124+      }
125+    } else {
126+      throw new ValueError("Function WORKDAY.INTL parameter 4 expects number values. But '" + weekend
127+        + "' cannot be coerced to a number.")
128+    }
129+  } else {
130+    weekendDays = [0, 6];
131+  }
132+  var hasHolidays = values.length === 3;
133+  var holidays = [];
134+  if (hasHolidays) {
135+    if (values[3] instanceof Array) {
136+      if (values[3].length === 0) {
137+        throw new RefError("Reference does not exist.");
138+      }
139+      for (var holidayDateValue of values[3]) {
140+        if (holidayDateValue instanceof ExcelDate) {
141+          holidays.push(holidayDateValue.toNumber());
142+        } else if (typeof holidayDateValue === "number") {
143+          holidays.push(holidayDateValue);
144+        } else {
145+          throw new ValueError("WORKDAY expects number values. But '" + holidayDateValue + "' is a " +
146+            (typeof holidayDateValue) + " and cannot be coerced to a number.")
147+        }
148+      }
149+    } else {
150+      holidays.push(TypeCaster.valueToNumber(values[3]));
151+    }
152+  }
153+  var cd = moment.utc(start.toMoment());
154+  var j = 0;
155+  while (j < days) {
156+    cd.add(1, 'days');
157+    if (weekendDays.indexOf(cd.day()) < 0 && holidays.indexOf(new ExcelDate(cd).toNumber()) < 0) {
158+      j++;
159+    }
160+  }
161+  return new ExcelDate(cd);
162+};
163 
164 export {
165   DATE,
166@@ -895,5 +1000,6 @@ export {
167   NOW,
168   TODAY,
169   TIME,
170-  WORKDAY
171+  WORKDAY,
172+  WORKDAY$INTL
173 }
174\ No newline at end of file
175diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
176index af7c60e..2c6e794 100644
177--- a/src/RawFormulas/RawFormulas.ts
178+++ b/src/RawFormulas/RawFormulas.ts
179@@ -131,7 +131,8 @@ import {
180   NOW,
181   TODAY,
182   TIME,
183-  WORKDAY
184+  WORKDAY,
185+  WORKDAY$INTL
186 } from "./Date"
187 
188 var ACCRINT = Formula["ACCRINT"];
189@@ -266,5 +267,6 @@ export {
190   NOW,
191   TODAY,
192   TIME,
193-  WORKDAY
194+  WORKDAY,
195+  WORKDAY$INTL
196 }
197\ No newline at end of file
198diff --git a/tests/DateFormulasTest.ts b/tests/DateFormulasTest.ts
199index d9045a3..1f07fed 100644
200--- a/tests/DateFormulasTest.ts
201+++ b/tests/DateFormulasTest.ts
202@@ -20,14 +20,49 @@ import {
203   NETWORKDAYS,
204   NETWORKDAYS$INTL,
205   TIME,
206-  WORKDAY
207+  WORKDAY,
208+  WORKDAY$INTL
209 } from "../src/RawFormulas/RawFormulas"
210 import * as ERRORS from "../src/Errors"
211 import {
212   assertEquals,
213   catchAndAssertEquals
214 } from "./utils/Asserts"
215-import moment = require("moment");
216+
217+
218+// Test WORKDAY.INTL
219+assertEquals(WORKDAY$INTL(DATE(1999, 2, 2), 10), DATE(1999, 2, 16));
220+assertEquals(WORKDAY$INTL(DATE(1999, 10, 10), 100), DATE(2000, 2, 25));
221+assertEquals(WORKDAY$INTL(DATE(1909, 12, 11), 222), DATE(1910, 10, 18));
222+assertEquals(WORKDAY$INTL(DATE(1922, 4, 1), 1234), DATE(1926, 12, 23));
223+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000), DATE(1968, 1, 12));
224+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000, "0000011"), DATE(1968, 1, 12));
225+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000, "1000001"), DATE(1968, 1, 13));
226+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000, "1100001"), DATE(1973, 10, 13));
227+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000, "1110000"), DATE(1973, 10, 14));
228+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000, "1110001"), DATE(1983, 5, 14));
229+assertEquals(WORKDAY$INTL(DATE(1945, 1, 14), 6000, 6), DATE(1968, 1, 14));
230+catchAndAssertEquals(function() {
231+  WORKDAY$INTL(12, 12, [12], false, 1);
232+}, ERRORS.NA_ERROR);
233+catchAndAssertEquals(function() {
234+  WORKDAY$INTL(12);
235+}, ERRORS.NA_ERROR);
236+catchAndAssertEquals(function() {
237+  WORKDAY$INTL("1992-1-1", "str");
238+}, ERRORS.VALUE_ERROR);
239+catchAndAssertEquals(function() {
240+  WORKDAY$INTL("1992-1-1", 12, []);
241+}, ERRORS.REF_ERROR);
242+catchAndAssertEquals(function() {
243+  WORKDAY$INTL("1992-1-1", 16, "000");
244+}, ERRORS.NUM_ERROR);
245+catchAndAssertEquals(function() {
246+  WORKDAY$INTL("1992-1-1", 12, 9);
247+}, ERRORS.NUM_ERROR);
248+catchAndAssertEquals(function() {
249+  WORKDAY$INTL("1992-1-1", 66, false);
250+}, ERRORS.VALUE_ERROR);
251 
252 
253 // Test WORKDAY
254diff --git a/tests/utils/Asserts.ts b/tests/utils/Asserts.ts
255index 2851607..ffbdded 100644
256--- a/tests/utils/Asserts.ts
257+++ b/tests/utils/Asserts.ts
258@@ -50,7 +50,7 @@ function catchAndAssertEquals(toExecute : Function, expected) {
259     toThrow = true;
260   } catch (actualError) {
261     if (actualError.name !== expected) {
262-      console.log("expected:", expected, " actual:", actualError.name);
263+      console.log("expected:", expected, " actual:", actualError.name, actualError.message);
264       console.trace();
265     }
266   }