spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[Date.ts] work-in-progress on eliminating need for ExcelDate
author
Ben Vogt <[email protected]>
date
2017-05-05 00:50:50
stats
4 file(s) changed, 77 insertions(+), 59 deletions(-)
files
src/ExcelDate.ts
src/Formulas/Date.ts
tests/Formulas/DateFormulasTest.ts
tests/Formulas/DateFormulasTestTimeOverride.ts
  1diff --git a/src/ExcelDate.ts b/src/ExcelDate.ts
  2index 7dffdd0..c60bf13 100644
  3--- a/src/ExcelDate.ts
  4+++ b/src/ExcelDate.ts
  5@@ -35,7 +35,11 @@ class ExcelDate {
  6    * @returns {number} days since 1900/1/1
  7    */
  8   toNumber() {
  9-    return Math.floor(this.seconds / SECONDS_IN_DAY);
 10+    return this.seconds / SECONDS_IN_DAY;
 11+  }
 12+
 13+  toNumberFloored() {
 14+    return Math.floor(this.toNumber());
 15   }
 16 
 17   /**
 18diff --git a/src/Formulas/Date.ts b/src/Formulas/Date.ts
 19index 068f33e..0c31829 100644
 20--- a/src/Formulas/Date.ts
 21+++ b/src/Formulas/Date.ts
 22@@ -24,10 +24,10 @@ import {
 23  * @param values[0] year - The year component of the date.
 24  * @param values[1] month - The month component of the date.
 25  * @param values[2] day - The day component of the date.
 26- * @returns {ExcelDate} newly created date.
 27+ * @returns {number} newly created date.
 28  * @constructor
 29  */
 30-var DATE = function (...values) : ExcelDate {
 31+var DATE = function (...values) : number {
 32   const FIRST_YEAR = 1900;
 33   ArgsChecker.checkLength(values, 3);
 34   var year = Math.abs(Math.floor(TypeCaster.firstValueAsNumber(values[0]))); // No negative values for year
 35@@ -43,7 +43,7 @@ var DATE = function (...values) : ExcelDate {
 36     throw new NumError("DATE evaluates to an out of range value " + excelDate.toNumber()
 37       + ". It should be greater than or equal to 0.");
 38   }
 39-  return excelDate;
 40+  return excelDate.toNumber();
 41 };
 42 
 43 /**
 44@@ -65,7 +65,7 @@ var DATEVALUE = function (...values) : number {
 45   }
 46 
 47   // If we've not been able to parse the date by now, then we cannot parse it at all.
 48-  return date.toNumber();
 49+  return date.toNumberFloored();
 50 };
 51 
 52 
 53@@ -76,7 +76,7 @@ var DATEVALUE = function (...values) : number {
 54  * @returns {ExcelDate} date a specified number of months before or after another date
 55  * @constructor
 56  */
 57-var EDATE = function (...values) : ExcelDate {
 58+var EDATE = function (...values) : number {
 59   ArgsChecker.checkLength(values, 2);
 60   var startDate = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
 61   if (startDate.toNumber() < 0) {
 62@@ -85,7 +85,7 @@ var EDATE = function (...values) : ExcelDate {
 63   var months = Math.floor(TypeCaster.firstValueAsNumber(values[1]));
 64   // While ExcelDate.toNumber() will return an inclusive count of days since 1900/1/1, moment.Moment.add assumes
 65   // exclusive count of days.
 66-  return new ExcelDate(moment.utc(ORIGIN_MOMENT).add(startDate.toNumber(), "days").add(months, "months"));
 67+  return new ExcelDate(moment.utc(ORIGIN_MOMENT).add(startDate.toNumber(), "days").add(months, "months")).toNumber();
 68 };
 69 
 70 
 71@@ -98,7 +98,7 @@ var EDATE = function (...values) : ExcelDate {
 72  * @returns {ExcelDate} the last day of a month
 73  * @constructor
 74  */
 75-var EOMONTH = function (...values) : ExcelDate {
 76+var EOMONTH = function (...values) : number {
 77   ArgsChecker.checkLength(values, 2);
 78   var startDate = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
 79   if (startDate.toNumber() < 0) {
 80@@ -107,7 +107,10 @@ var EOMONTH = function (...values) : ExcelDate {
 81   var months = Math.floor(TypeCaster.firstValueAsNumber(values[1]));
 82   // While ExcelDate.toNumber() will return an inclusive count of days since 1900/1/1, moment.Moment.add assumes
 83   // exclusive count of days.
 84-  return new ExcelDate(moment.utc(ORIGIN_MOMENT).add(startDate.toNumber(), "days").add(months, "months").endOf("month"));
 85+  return new ExcelDate(moment.utc(ORIGIN_MOMENT)
 86+      .add(startDate.toNumber(), "days")
 87+      .add(months, "months")
 88+      .endOf("month")).toNumberFloored();
 89 };
 90 
 91 
 92@@ -159,7 +162,7 @@ var DAYS = function (...values) : number {
 93  * @returns {number} of days between two dates
 94  * @constructor
 95  */
 96-var DAYS360 = function (...values) {
 97+var DAYS360 = function (...values) : number {
 98   ArgsChecker.checkLengthWithin(values, 2, 3);
 99   var start = TypeCaster.firstValueAsExcelDate(values[0], true).toMoment(); // tell firstValueAsExcelDate to coerce boolean
100   var end = TypeCaster.firstValueAsExcelDate(values[1], true).toMoment(); // tell firstValueAsExcelDate to coerce boolean
101@@ -215,7 +218,7 @@ var MONTH = function (...values) : number {
102  * @returns {number} year of the input date
103  * @constructor
104  */
105-var YEAR = function (...values) {
106+var YEAR = function (...values) : number {
107   ArgsChecker.checkLength(values, 1);
108   var date = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
109   if (date.toNumber() < 0) {
110@@ -237,7 +240,7 @@ var YEAR = function (...values) {
111  * @returns {number} day of week
112  * @constructor
113  */
114-var WEEKDAY = function (...values) {
115+var WEEKDAY = function (...values) : number {
116   ArgsChecker.checkLengthWithin(values, 1, 2);
117   var date = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
118   var offsetType = values.length === 2 ? TypeCaster.firstValueAsNumber(values[1]) : 1;
119@@ -296,7 +299,7 @@ function calculateWeekNum(dm : moment.Moment, shifterArray : Array<number>) : nu
120  * @returns {number} representing week number of year.
121  * @constructor
122  */
123-var WEEKNUM = function (...values) {
124+var WEEKNUM = function (...values) : number {
125   ArgsChecker.checkLengthWithin(values, 1, 2);
126   var date = TypeCaster.firstValueAsExcelDate(values[0], true); // tell firstValueAsExcelDate to coerce boolean
127   var shiftType = values.length === 2 ? TypeCaster.firstValueAsNumber(values[1]) : 1;
128@@ -570,7 +573,7 @@ var HOUR = function (...values) : number {
129  * @returns {number} minute of the time passed in.
130  * @constructor
131  */
132-var MINUTE = function (...values) {
133+var MINUTE = function (...values) : number {
134   ArgsChecker.checkLength(values, 1);
135   var time = TypeCaster.firstValueAsTimestampNumber(values[0]);
136   if (time % 1 === 0) {
137@@ -778,9 +781,9 @@ var NETWORKDAYS$INTL = function (...values) : number {
138  * @returns {ExcelDate} representing the current date and time.
139  * @constructor
140  */
141-var NOW = function (...values) : ExcelDate {
142+var NOW = function (...values) : number {
143   ArgsChecker.checkLength(values, 0);
144-  return new ExcelDate(moment());
145+  return new ExcelDate(moment.utc()).toNumber();
146 };
147 
148 /**
149@@ -788,9 +791,9 @@ var NOW = function (...values) : ExcelDate {
150  * @returns {ExcelDate} today
151  * @constructor
152  */
153-var TODAY = function (...values) {
154+var TODAY = function (...values) : number {
155   ArgsChecker.checkLength(values, 0);
156-  return new ExcelDate(moment().startOf("day"));
157+  return new ExcelDate(moment.utc().startOf("day")).toNumberFloored();
158 };
159 
160 
161@@ -803,13 +806,13 @@ var TODAY = function (...values) {
162  * @returns {ExcelTime} time
163  * @constructor
164  */
165-var TIME = function (...values) : ExcelTime {
166+var TIME = function (...values) : number {
167   ArgsChecker.checkLength(values, 3);
168   var hours = Math.floor(TypeCaster.firstValueAsNumber(values[0]));
169   var minutes = Math.floor(TypeCaster.firstValueAsNumber(values[1]));
170   var seconds = Math.floor(TypeCaster.firstValueAsNumber(values[2]));
171-  var e = new ExcelTime(hours, minutes, seconds);
172-  if (e.toNumber() < 0) {
173+  var e = new ExcelTime(hours, minutes, seconds).toNumber();
174+  if (e < 0) {
175     throw new NumError("TIME evaluates to an out of range value -1.201273148. It should be greater than or equal to 0.");
176   }
177   return e;
178@@ -828,7 +831,7 @@ var TIME = function (...values) : ExcelTime {
179  * @returns {ExcelDate} end date after a specified number of working days.
180  * @constructor
181  */
182-var WORKDAY = function (...values) {
183+var WORKDAY = function (...values) : number {
184   ArgsChecker.checkLengthWithin(values, 2, 3);
185   var start = TypeCaster.firstValueAsExcelDate(values[0], true);
186   var days = TypeCaster.firstValueAsNumber(values[1]);
187@@ -863,7 +866,7 @@ var WORKDAY = function (...values) {
188       j++;
189     }
190   }
191-  return new ExcelDate(cd);
192+  return new ExcelDate(cd).toNumber();
193 };
194 
195 
196@@ -882,7 +885,7 @@ var WORKDAY = function (...values) {
197  * @returns {ExcelDate}
198  * @constructor
199  */
200-var WORKDAY$INTL = function (...values) {
201+var WORKDAY$INTL = function (...values) : number {
202   ArgsChecker.checkLengthWithin(values, 2, 3);
203   var start = TypeCaster.firstValueAsExcelDate(values[0], true);
204   var days = TypeCaster.firstValueAsNumber(values[1]);
205@@ -962,7 +965,7 @@ var WORKDAY$INTL = function (...values) {
206       j++;
207     }
208   }
209-  return new ExcelDate(cd);
210+  return new ExcelDate(cd).toNumber();
211 };
212 
213 export {
214diff --git a/tests/Formulas/DateFormulasTest.ts b/tests/Formulas/DateFormulasTest.ts
215index ea01357..5b381bc 100644
216--- a/tests/Formulas/DateFormulasTest.ts
217+++ b/tests/Formulas/DateFormulasTest.ts
218@@ -86,20 +86,20 @@ test("WORKDAY", function () {
219 
220 
221 test("TIME", function () {
222-  assertEquals(TIME(10, 10, 10).toNumber(), 0.4237268518518518);
223-  assertEquals(TIME(34, 10, 10).toNumber(), 0.4237268518518518);
224-  assertEquals(TIME(29, 10, 10).toNumber(), 0.2153935185185185);
225-  assertEquals(TIME(13, 9, 6).toNumber(), 0.5479861111111111);
226-  assertEquals(TIME(3, 1, 14).toNumber(), 0.12585648148148149);
227-  assertEquals(TIME(0, 0, 0).toNumber(), 0);
228-  assertEquals(TIME(24, 0, 0).toNumber(), 0);
229-  assertEquals(TIME(23, 60, 0).toNumber(), 0);
230-  assertEquals(TIME(23, 59, 60).toNumber(), 0);
231-  assertEquals(TIME(18, 0, 0).toNumber(), 0.75);
232-  assertEquals(TIME(12, 0, 0).toNumber(), 0.5);
233-  assertEquals(TIME(6, 0, 0).toNumber(), 0.25);
234-  assertEquals(TIME(3, 0, 0).toNumber(), 0.125);
235-  assertEquals(TIME("3", ["0"], false).toNumber(), 0.125);
236+  assertEquals(TIME(10, 10, 10), 0.4237268518518518);
237+  assertEquals(TIME(34, 10, 10), 0.4237268518518518);
238+  assertEquals(TIME(29, 10, 10), 0.2153935185185185);
239+  assertEquals(TIME(13, 9, 6), 0.5479861111111111);
240+  assertEquals(TIME(3, 1, 14), 0.12585648148148149);
241+  assertEquals(TIME(0, 0, 0), 0);
242+  assertEquals(TIME(24, 0, 0), 0);
243+  assertEquals(TIME(23, 60, 0), 0);
244+  assertEquals(TIME(23, 59, 60), 0);
245+  assertEquals(TIME(18, 0, 0), 0.75);
246+  assertEquals(TIME(12, 0, 0), 0.5);
247+  assertEquals(TIME(6, 0, 0), 0.25);
248+  assertEquals(TIME(3, 0, 0), 0.125);
249+  assertEquals(TIME("3", ["0"], false), 0.125);
250   catchAndAssertEquals(function() {
251     TIME();
252   }, ERRORS.NA_ERROR);
253@@ -1375,9 +1375,9 @@ test("EOMONTH", function(){
254 
255 
256 test("DATE", function(){
257-  assertEquals(DATE(1900, 1, 2).toNumber(), 3);
258-  assertEquals(DATE(1900, 1, 1).toNumber(), 2);
259-  assertEquals(DATE(1900, 1, 4).toNumber(), 5);
260+  assertEquals(DATE(1900, 1, 2), 3);
261+  assertEquals(DATE(1900, 1, 1), 2);
262+  assertEquals(DATE(1900, 1, 4), 5);
263   catchAndAssertEquals(function() {
264     DATE(1900, 0, 5);
265   }, ERRORS.NUM_ERROR);
266@@ -1387,20 +1387,20 @@ test("DATE", function(){
267   catchAndAssertEquals(function() {
268     DATE(1900, 0);
269   }, ERRORS.NA_ERROR);
270-  assertEquals(DATE(1992, 6, 24).toNumber(), 33779);
271-  assertEquals(DATE(2017, 2, 26).toNumber(), 42792);
272-  assertEquals(DATE(1999, 1, 13).toNumber(), 36173);
273+  assertEquals(DATE(1992, 6, 24), 33779);
274+  assertEquals(DATE(2017, 2, 26), 42792);
275+  assertEquals(DATE(1999, 1, 13), 36173);
276   // Leap day stuff
277-  assertEquals(DATE(2004, 2, 28).toNumber(), 38045);
278-  assertEquals(DATE(2004, 2, 29).toNumber(), 38046);
279-  assertEquals(DATE(2004, 3, 1).toNumber(), 38047);
280+  assertEquals(DATE(2004, 2, 28), 38045);
281+  assertEquals(DATE(2004, 2, 29), 38046);
282+  assertEquals(DATE(2004, 3, 1), 38047);
283   // Overflow values
284-  assertEquals(DATE(1992, 6, 44).toNumber(), 33799);
285-  assertEquals(DATE(2, 33, 44).toNumber(), 1749);
286-  assertEquals(DATE(1777, 33, 44).toNumber(), 650055);
287-  assertEquals(DATE(1976, 2, -10).toNumber(), 27780);
288-  assertEquals(DATE(-1900, 1, 1).toNumber(), 2);
289-  assertEquals(DATE(1992, 1, 10).toNumber(), 33613);
290+  assertEquals(DATE(1992, 6, 44), 33799);
291+  assertEquals(DATE(2, 33, 44), 1749);
292+  assertEquals(DATE(1777, 33, 44), 650055);
293+  assertEquals(DATE(1976, 2, -10), 27780);
294+  assertEquals(DATE(-1900, 1, 1), 2);
295+  assertEquals(DATE(1992, 1, 10), 33613);
296 });
297 
298 
299diff --git a/tests/Formulas/DateFormulasTestTimeOverride.ts b/tests/Formulas/DateFormulasTestTimeOverride.ts
300index bac084a..55c6945 100644
301--- a/tests/Formulas/DateFormulasTestTimeOverride.ts
302+++ b/tests/Formulas/DateFormulasTestTimeOverride.ts
303@@ -24,13 +24,13 @@ function lockDate(year, month, day, hour, minute, second) {
304 
305 test("NOW", function(){
306   lockDate(2012, 11, 10, 4, 55, 4);
307-  assertEquals(NOW().toNumber(), DATEVALUE("Dec 10 2012"));
308+  assertEquals(NOW(), 41253.45490740741);
309   lockDate(1999, 11, 10, 4, 55, 4);
310-  assertEquals(NOW().toNumber(), DATEVALUE("Dec 10 1999"));
311+  assertEquals(NOW(), 36504.45490740741);
312   lockDate(1999, 9, 22, 4, 55, 4);
313-  assertEquals(NOW().toNumber(), DATEVALUE("Oct 22 1999"));
314+  assertEquals(NOW(), 36455.41324074074);
315   lockDate(1944, 1, 2, 1, 11, 55);
316-  assertEquals(NOW().toNumber(), DATEVALUE("Feb 2 1944"));
317+  assertEquals(NOW(), 16104.29994212963);
318   catchAndAssertEquals(function() {
319     NOW(12);
320   }, ERRORS.NA_ERROR);
321@@ -39,13 +39,13 @@ test("NOW", function(){
322 
323 test("TODAY", function(){
324   lockDate(2012, 11, 10, 4, 55, 4);
325-  assertEquals(TODAY().toNumber(), DATEVALUE("Dec 10 2012"));
326+  assertEquals(TODAY(), DATEVALUE("Dec 10 2012"));
327   lockDate(1999, 11, 10, 4, 55, 4);
328-  assertEquals(TODAY().toNumber(), DATEVALUE("Dec 10 1999"));
329+  assertEquals(TODAY(), DATEVALUE("Dec 10 1999"));
330   lockDate(1999, 9, 22, 4, 55, 4);
331-  assertEquals(TODAY().toNumber(), DATEVALUE("Oct 22 1999"));
332+  assertEquals(TODAY(), DATEVALUE("Oct 22 1999"));
333   lockDate(1944, 1, 2, 1, 11, 55);
334-  assertEquals(TODAY().toNumber(), DATEVALUE("Feb 2 1944"));
335+  assertEquals(TODAY(), DATEVALUE("Feb 2 1944"));
336   catchAndAssertEquals(function() {
337     TODAY(12);
338   }, ERRORS.NA_ERROR);