spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
Working on custom version of ACCRINT
author
Ben Vogt <[email protected]>
date
2017-01-08 22:20:45
stats
2 file(s) changed, 171 insertions(+), 2 deletions(-)
files
src/SupportedFormulas.ts
tests/SheetFormulaTest.ts
  1diff --git a/src/SupportedFormulas.ts b/src/SupportedFormulas.ts
  2index 098a593..52b9eb7 100644
  3--- a/src/SupportedFormulas.ts
  4+++ b/src/SupportedFormulas.ts
  5@@ -1,5 +1,6 @@
  6 /// <reference path="../node_modules/moment/moment.d.ts"/>
  7 import * as moment from "moment";
  8+import * as Formula from "formulajs"
  9 
 10 const SUPPORTED_FORMULAS = [
 11   'ABS', 'ACCRINT', 'ACOS', 'ACOSH', 'ACOTH', 'AND', 'ARABIC', 'ASIN', 'ASINH', 'ATAN', 'ATAN2', 'ATANH', 'AVEDEV', 'AVERAGE', 'AVERAGEA', 'AVERAGEIF',
 12@@ -39,6 +40,169 @@ const OverrideFormulas = {
 13   },
 14   TAN: function (rad) {
 15     return rad === Math.PI ? 0 : Math.tan(rad);
 16+  },
 17+  ACCRINT: function (issue, first, settlement, rate, par, frequency, basis) {
 18+    // Return error if either date is invalid
 19+    if (!moment(issue).isValid() || !moment(first).isValid() || !moment(settlement).isValid()) {
 20+      return '#VALUE!';
 21+    }
 22+
 23+    // Set default values
 24+    par = (typeof par === 'undefined') ? 0 : par;
 25+    basis = (typeof basis === 'undefined') ? 0 : basis;
 26+
 27+    // Return error if either rate or par are lower than or equal to zero
 28+    if (rate <= 0 || par <= 0) {
 29+      return '#NUM!';
 30+    }
 31+
 32+    // Return error if frequency is neither 1, 2, or 4
 33+    if ([1, 2, 4].indexOf(frequency) === -1) {
 34+      return '#NUM!';
 35+    }
 36+
 37+    // Return error if basis is neither 0, 1, 2, 3, or 4
 38+    if ([0, 1, 2, 3, 4].indexOf(basis) === -1) {
 39+      return '#NUM!';
 40+    }
 41+
 42+    // Return error if issue greater than or equal to settlement
 43+    if (moment(issue).diff(moment(settlement)) >= 0) {
 44+      return '#NUM!';
 45+    }
 46+
 47+    // Compute accrued interest
 48+    var factor : any = 0;
 49+    switch (basis) {
 50+      case 0:
 51+        // US (NASD) 30/360
 52+        factor = OverrideFormulas.YEARFRAC(issue, settlement, basis);
 53+        break;
 54+      case 1:
 55+        // Actual/actual
 56+        factor = OverrideFormulas.YEARFRAC(issue, settlement, basis);
 57+        break;
 58+      case 2:
 59+        // Actual/360
 60+        factor = OverrideFormulas.YEARFRAC(issue, settlement, basis);
 61+        break;
 62+      case 3:
 63+        // Actual/365
 64+        factor = OverrideFormulas.YEARFRAC(issue, settlement, basis);
 65+        break;
 66+      case 4:
 67+        // European 30/360
 68+        factor = OverrideFormulas.YEARFRAC(issue, settlement, basis);
 69+        break;
 70+    }
 71+    return par * rate * factor;
 72+  },
 73+  YEARFRAC: function (start_date, end_date, basis) : any {
 74+    basis = (typeof basis === 'undefined') ? 0 : basis;
 75+    var sdate = moment(new Date(start_date));
 76+    var edate = moment(new Date(end_date));
 77+
 78+    // Return error if either date is invalid
 79+    if (!sdate.isValid() || !edate.isValid()) {
 80+      return '#VALUE!';
 81+    }
 82+
 83+    // Return error if basis is neither 0, 1, 2, 3, or 4
 84+    if ([0, 1, 2, 3, 4].indexOf(basis) === -1) {
 85+      return '#NUM!';
 86+    }
 87+
 88+    // Return zero if start_date and end_date are the same
 89+    if (sdate === edate) {
 90+      return 0;
 91+    }
 92+
 93+    // Swap dates if start_date is later than end_date
 94+    if (sdate.diff(edate) > 0) {
 95+      edate = moment(new Date(start_date));
 96+      sdate = moment(new Date(end_date));
 97+    }
 98+
 99+    // Lookup years, months, and days
100+    var syear = sdate.year();
101+    var smonth = sdate.month();
102+    var sday = sdate.date();
103+    var eyear = edate.year();
104+    var emonth = edate.month();
105+    var eday = edate.date();
106+
107+    switch (basis) {
108+      case 0:
109+        // US (NASD) 30/360
110+        // Note: if eday == 31, it stays 31 if sday < 30
111+        if (sday === 31 && eday === 31) {
112+          sday = 30;
113+          eday = 30;
114+        } else if (sday === 31) {
115+          sday = 30;
116+        } else if (sday === 30 && eday === 31) {
117+          eday = 30;
118+        } else if (smonth === 1 && emonth === 1 && sdate.daysInMonth() === sday && edate.daysInMonth() === eday) {
119+          sday = 30;
120+          eday = 30;
121+        } else if (smonth === 1 && sdate.daysInMonth() === sday) {
122+          sday = 30;
123+        }
124+        return ((eday + emonth * 30 + eyear * 360) - (sday + smonth * 30 + syear * 360)) / 360;
125+
126+      case 1:
127+        // Actual/actual
128+        var feb29Between = function (date1, date2) {
129+          // Requires year2 == (year1 + 1) or year2 == year1
130+          // Returns TRUE if February 29 is between the two dates (date1 may be February 29), with two possibilities:
131+          // year1 is a leap year and date1 <= Februay 29 of year1
132+          // year2 is a leap year and date2 > Februay 29 of year2
133+
134+          var mar1year1 = moment(new Date(date1.year(), 2, 1));
135+          if (moment([date1.year()]).isLeapYear() && date1.diff(mar1year1) < 0 && date2.diff(mar1year1) >= 0) {
136+            return true;
137+          }
138+          var mar1year2 = moment(new Date(date2.year(), 2, 1));
139+          if (moment([date2.year()]).isLeapYear() && date2.diff(mar1year2) >= 0 && date1.diff(mar1year2) < 0) {
140+            return true;
141+          }
142+          return false;
143+        };
144+        var ylength = 365;
145+        if (syear === eyear || ((syear + 1) === eyear) && ((smonth > emonth) || ((smonth === emonth) && (sday >= eday)))) {
146+          if (syear === eyear && moment([syear]).isLeapYear()) {
147+            ylength = 366;
148+          } else if (feb29Between(sdate, edate) || (emonth === 1 && eday === 29)) {
149+            ylength = 366;
150+          }
151+          return edate.diff(sdate, 'days') / ylength;
152+        } else {
153+          var years = (eyear - syear) + 1;
154+          var days = moment(new Date(eyear + 1, 0, 1)).diff(moment(new Date(syear, 0, 1)), 'days');
155+          var average = days / years;
156+          return edate.diff(sdate, 'days') / average;
157+        }
158+
159+      case 2:
160+        // Actual/360
161+        return edate.diff(sdate, 'days') / 360;
162+
163+      case 3:
164+        // Actual/365
165+        return edate.diff(sdate, 'days') / 365;
166+
167+      case 4:
168+        // European 30/360
169+        if (sday === 31) {
170+          sday = 30;
171+        }
172+
173+        if (eday === 31) {
174+          eday = 30;
175+        }
176+        // Remarkably, do NOT change February 28 or February 29 at ALL
177+        return ((eday + emonth * 30 + eyear * 360) - (sday + smonth * 30 + syear * 360)) / 360;
178+    }
179   }
180 };
181 
182diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
183index 96083d8..09ebb49 100644
184--- a/tests/SheetFormulaTest.ts
185+++ b/tests/SheetFormulaTest.ts
186@@ -33,7 +33,9 @@ testFormula("=ABS(-10)", 10);
187 testFormula("=ABS(0)", 0);
188 
189 // Test ACCRINT
190-// TODO: this
191+// TODO: The second one is really close, but should be correct. Fix this.
192+testFormula("=ACCRINT(DATE(2011, 1, 1), DATE(2011, 2, 1), DATE(2014, 7, 1), 0.1, 1000, 1, 0)", 350);
193+// testFormula('=ACCRINT(DATE(2010, 1, 1), DATE(2010, 2, 1), DATE(2012, 12, 31), 0.05, 100, 4)', 14.98611111);
194 
195 // Test ACOS
196 testFormula("=ACOS(0)", 1.5707963267948966);
197@@ -289,7 +291,7 @@ testFormula('=DOLLARFR(100.1, 32)', 100.032);
198 testFormula('=AND(10)', true);
199 
200 // Test EDATE
201-testFormulaToDate('=EDATE(DATE(1992, 6, 24), 1)', new Date('Fri Jul 24 1992 00:00:00 GMT-0500 (CDT)').getTime());
202+testFormulaToDate('=EDATE(DATE(1992, 6, 24), 1)', new Date('7/24/1992').getTime());
203 
204 // Test EFFECT
205 testFormula('=EFFECT(0.99, 12)', 1.5890167507927795);
206@@ -464,3 +466,6 @@ testFormula('=TRUNC(3.1415, 2)', 3.14);
207 
208 // Test XOR
209 testFormula('=XOR(1, 1)', false);
210+
211+// Test YEARFRAC
212+testFormula('=YEARFRAC(DATE(1969,7,16), DATE(1969,7,24), 1)', 0.021917808219178082);
213\ No newline at end of file