spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[EDATE, DAY, EOMONTH] checking for boolean values and converting
author
Ben Vogt <[email protected]>
date
2017-04-02 23:43:17
stats
4 file(s) changed, 95 insertions(+), 12 deletions(-)
files
README.md
src/RawFormulas/Date.ts
src/RawFormulas/Utils.ts
tests/DateFormulasTest.ts
  1diff --git a/README.md b/README.md
  2index 5b95a00..a02f0b6 100644
  3--- a/README.md
  4+++ b/README.md
  5@@ -41,11 +41,10 @@ conversion inside parser.js.
  6 * Test all ExcelDate functions
  7 Right now we're just using the number of days since 1900, but we should check the other functions.
  8 
  9-* Verify that all white-space wild cards are implemented properly
 10-
 11 * Verify that all N-times ({2,9}) are correct, and we're not parsing numbers too big.
 12 
 13 
 14+
 15 # Testing Guidelines
 16 
 17 All formulas should test for:
 18diff --git a/src/RawFormulas/Date.ts b/src/RawFormulas/Date.ts
 19index 587cc82..4f0c47e 100644
 20--- a/src/RawFormulas/Date.ts
 21+++ b/src/RawFormulas/Date.ts
 22@@ -72,7 +72,10 @@ var DATEVALUE = function (...values) : number {
 23  */
 24 var EDATE = function (...values) : ExcelDate {
 25   ArgsChecker.checkLength(values, 2);
 26-  var startDate = TypeCaster.firstValueAsExcelDate(values[0]);
 27+  var startDate = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
 28+  if (startDate.toNumber() < 0) {
 29+    throw new NumError("Function EDATE parameter 1 value is " + startDate.toNumber() + ". It should be greater than or equal to 0.");
 30+  }
 31   var months = Math.floor(TypeCaster.firstValueAsNumber(values[1]));
 32   // While ExcelDate.toNumber() will return an inclusive count of days since 1900/1/1, moment.Moment.add assumes
 33   // exclusive count of days.
 34@@ -91,7 +94,10 @@ var EDATE = function (...values) : ExcelDate {
 35  */
 36 var EOMONTH = function (...values) : ExcelDate {
 37   ArgsChecker.checkLength(values, 2);
 38-  var startDate = TypeCaster.firstValueAsExcelDate(values[0]);
 39+  var startDate = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
 40+  if (startDate.toNumber() < 0) {
 41+    throw new NumError("Function EOMONTH parameter 1 value is " + startDate.toNumber() + ". It should be greater than or equal to 0.");
 42+  }
 43   var months = Math.floor(TypeCaster.firstValueAsNumber(values[1]));
 44   // While ExcelDate.toNumber() will return an inclusive count of days since 1900/1/1, moment.Moment.add assumes
 45   // exclusive count of days.
 46@@ -99,7 +105,24 @@ var EOMONTH = function (...values) : ExcelDate {
 47 };
 48 
 49 
 50-var DAY = Formula["DAY"];
 51+/**
 52+ * Returns the day of the month that a specific date falls on, in numeric format.
 53+ * @param values[0] date - The date from which to extract the day. Must be a reference to a cell containing a date, a
 54+ * function returning a date type, or a number.
 55+ * @returns {number} day of the month
 56+ * @constructor
 57+ */
 58+var DAY = function (...values) : number {
 59+  ArgsChecker.checkLength(values, 1);
 60+  var date = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
 61+  if (date.toNumber() < 0) {
 62+    throw new NumError("Function DAY parameter 1 value is " + date.toNumber() + ". It should be greater than or equal to 0.");
 63+  }
 64+  return date.toMoment().date();
 65+};
 66+
 67+
 68+
 69 var DAYS = Formula["DAYS"];
 70 var DAYS360 = Formula["DAYS360"];
 71 
 72diff --git a/src/RawFormulas/Utils.ts b/src/RawFormulas/Utils.ts
 73index 2be95f1..ddda75c 100644
 74--- a/src/RawFormulas/Utils.ts
 75+++ b/src/RawFormulas/Utils.ts
 76@@ -732,24 +732,26 @@ class TypeCaster {
 77   /**
 78    * Takes the input type and will throw a REF_ERROR or coerce it into a ExcelDate
 79    * @param input input to attempt to coerce to a ExcelDate
 80+   * @param coerceBoolean should a boolean be converted
 81    * @returns {ExcelDate} representing a date
 82    */
 83-  static firstValueAsExcelDate(input: any) : ExcelDate {
 84+  static firstValueAsExcelDate(input: any, coerceBoolean?: boolean) : ExcelDate {
 85     if (input instanceof Array) {
 86       if (input.length === 0) {
 87         throw new RefError("Reference does not exist.");
 88       }
 89-      return TypeCaster.firstValueAsExcelDate(input[0]);
 90+      return TypeCaster.firstValueAsExcelDate(input[0], coerceBoolean);
 91     }
 92-    return TypeCaster.valueToExcelDate(input);
 93+    return TypeCaster.valueToExcelDate(input, coerceBoolean);
 94   }
 95 
 96   /**
 97    * Convert a value to ExcelDate if possible.
 98-   * @param value of any type, including array. array cannot be empty.
 99+   * @param value to convert
100+   * @param coerceBoolean should a boolean be converted
101    * @returns {ExcelDate} ExcelDate
102    */
103-  static valueToExcelDate(value: any) : ExcelDate {
104+  static valueToExcelDate(value: any, coerceBoolean?: boolean) : ExcelDate {
105     if (value instanceof ExcelDate) {
106       return value;
107     } else if (typeof value === "number") {
108@@ -764,7 +766,10 @@ class TypeCaster {
109         throw new ValueError("___ expects date values. But '" + value + "' is a text and cannot be coerced to a date.")
110       }
111     } else if (typeof value === "boolean") {
112-      throw new ValueError("___ expects date values. But '" + value + "' is a text and cannot be coerced to a date.")
113+      if (coerceBoolean) {
114+        return new ExcelDate(value ? 1 : 0);
115+      }
116+      throw new ValueError("___ expects date values. But '" + value + "' is a boolean and cannot be coerced to a date.")
117     }
118   }
119 }
120diff --git a/tests/DateFormulasTest.ts b/tests/DateFormulasTest.ts
121index d1f5635..330ad1c 100644
122--- a/tests/DateFormulasTest.ts
123+++ b/tests/DateFormulasTest.ts
124@@ -1,5 +1,5 @@
125 
126-import { DATE, DATEVALUE, EDATE, EOMONTH } from "../src/RawFormulas/RawFormulas"
127+import { DATE, DATEVALUE, EDATE, EOMONTH, DAY } from "../src/RawFormulas/RawFormulas"
128 import * as ERRORS from "../src/Errors"
129 import {assertEquals} from "./utils/Asserts"
130 import moment = require("moment");
131@@ -18,6 +18,36 @@ function catchAndAssertEquals(toExecute, expected) {
132     throw new Error("expected error: " + expected);
133   }
134 }
135+
136+// Test DAY
137+assertEquals(DAY(DATE(1992, 6, 24)), 24);
138+assertEquals(DAY(DATE(1992, 5, 10)), 10);
139+assertEquals(DAY(DATE(1992, 5, 22)), 22);
140+assertEquals(DAY(DATE(1992, 6, 1)), 1);
141+assertEquals(DAY(DATE(2008, 1, 31)), 31);
142+assertEquals(DAY("1992, 6, 24"), 24);
143+assertEquals(DAY(["1992, 6, 24"]), 24);
144+assertEquals(DAY(0), 30);
145+assertEquals(DAY(false), 30);
146+assertEquals(DAY(1), 31);
147+assertEquals(DAY(true), 31);
148+assertEquals(DAY(33779), 24);
149+assertEquals(DAY([33779]), 24);
150+assertEquals(DAY([33779, "str"]), 24);
151+catchAndAssertEquals(function() {
152+  DAY("str");
153+}, ERRORS.VALUE_ERROR);
154+catchAndAssertEquals(function() {
155+  DAY();
156+}, ERRORS.NA_ERROR);
157+catchAndAssertEquals(function() {
158+  DAY(DATE(1992, 6, 24), 4);
159+}, ERRORS.NA_ERROR);
160+catchAndAssertEquals(function() {
161+  DAY(-1);
162+}, ERRORS.NUM_ERROR);
163+
164+
165 // Test EDATE
166 assertEquals(EDATE(DATE(1992, 6, 24), 1), DATE(1992, 7, 24));
167 assertEquals(EDATE(DATE(1992, 5, 24), 2), DATE(1992, 7, 24));
168@@ -27,6 +57,8 @@ assertEquals(EDATE(DATE(1992, 6, 24), false), DATE(1992, 6, 24));
169 assertEquals(EDATE("1992, 5, 24", 2), DATE(1992, 7, 24));
170 assertEquals(EDATE("6/24/92", 1), DATE(1992, 7, 24));
171 assertEquals(EDATE([DATE(1992, 6, 24), "str"], [1, "str"]), DATE(1992, 7, 24));
172+assertEquals(EDATE(0, 1), DATE(1900, 1, 30));
173+assertEquals(EDATE(false, 1), DATE(1900, 1, 30));
174 catchAndAssertEquals(function() {
175   EDATE("str", 2);
176 }, ERRORS.VALUE_ERROR);
177@@ -36,6 +68,12 @@ catchAndAssertEquals(function() {
178 catchAndAssertEquals(function() {
179   EDATE(DATE(1992, 6, 24), 4, 4);
180 }, ERRORS.NA_ERROR);
181+catchAndAssertEquals(function() {
182+  EDATE(-1, 1);
183+}, ERRORS.NUM_ERROR);
184+catchAndAssertEquals(function() {
185+  EDATE(DATEVALUE("01/13/0101"), 1);
186+}, ERRORS.NUM_ERROR);
187 
188 
189 // Test EOMONTH
190@@ -52,12 +90,16 @@ assertEquals(EOMONTH(DATE(2004, 2, 24), 0), DATE(2004, 2, 29));
191 assertEquals(EOMONTH(DATE(2008, 2, 24), 0), DATE(2008, 2, 29));
192 // misc.
193 assertEquals(EOMONTH([DATE(1992, 6, 24), "str"], [2, "str"]), DATE(1992, 8, 31));
194+assertEquals(EOMONTH(0, 1), DATE(1900, 1, 31));
195+assertEquals(EOMONTH(false, 1), DATE(1900, 1, 31));
196+assertEquals(EOMONTH(1, 1), DATE(1900, 1, 31));
197+assertEquals(EOMONTH(true, 1), DATE(1900, 1, 31));
198 catchAndAssertEquals(function() {
199   EOMONTH("str", 2);
200 }, ERRORS.VALUE_ERROR);
201 catchAndAssertEquals(function() {
202-  EOMONTH(false, 2);
203-}, ERRORS.VALUE_ERROR);
204+  EOMONTH(-1, 2);
205+}, ERRORS.NUM_ERROR);
206 
207 
208 // Test DATE
209@@ -98,6 +140,9 @@ catchAndAssertEquals(function() {
210 catchAndAssertEquals(function() {
211   DATEVALUE();
212 }, ERRORS.NA_ERROR);
213+catchAndAssertEquals(function() {
214+  DATEVALUE(false);
215+}, ERRORS.VALUE_ERROR);
216 // MONTHDIG_DAY_YEAR, MM(fd)DD(fd)YYYY =================================================================================
217 assertEquals(DATEVALUE("6/24/92"), 33779);
218 assertEquals(DATEVALUE("6/24/1992"), 33779);