spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[ACCRINT] work-in-progress, ironing out small errors between gs + mse implementations
author
Ben Vogt <[email protected]>
date
2017-04-29 18:23:45
stats
6 file(s) changed, 95 insertions(+), 5 deletions(-)
files
README.md
src/RawFormulas/Date.ts
src/RawFormulas/Financial.ts
src/RawFormulas/RawFormulas.ts
tests/DateFormulasTest.ts
tests/FormulasTest.ts
  1diff --git a/README.md b/README.md
  2index 4f78313..b5b5950 100644
  3--- a/README.md
  4+++ b/README.md
  5@@ -30,8 +30,6 @@ See `DOLLAR` function for more info.
  6 ### Get a better way to tie formulas into single export
  7 Listing them inside RawFormulas.ts is unwieldy.
  8 
  9-### Use `arguments` instead of `...values` for performance reasons.
 10-
 11 ### Error formatting
 12 Pass name of calling formula into all functions that throw user-facing errors, or have some sort of error mapper.
 13 
 14@@ -57,6 +55,9 @@ Right now we're just using the number of days since 1900, but we should check th
 15 
 16 ### Numbers with commas in them should still parse to numbers.
 17 
 18+### Break tests out by category.
 19+
 20+
 21 ## Testing Guidelines
 22 
 23 All formulas should test for:
 24diff --git a/src/RawFormulas/Date.ts b/src/RawFormulas/Date.ts
 25index c681308..c320ed3 100644
 26--- a/src/RawFormulas/Date.ts
 27+++ b/src/RawFormulas/Date.ts
 28@@ -439,6 +439,13 @@ var DATEDIF = function (...values) : number {
 29 
 30 /**
 31  * Returns the number of years, including fractional years, between two dates using a specified day count convention.
 32+ *
 33+ * Further reading:
 34+ *
 35+ * * http://christian-fries.de/blog/files/2013-yearfrac.html
 36+ *
 37+ * * http://finmath.net/finmath-lib/
 38+ *
 39  * @param values[0] start_date - The start date to consider in the calculation. Must be a reference to a cell
 40  * containing a date, a function returning a date type, or a number.
 41  * @param values[1] end_date - The end date to consider in the calculation. Must be a reference to a cell containing
 42diff --git a/src/RawFormulas/Financial.ts b/src/RawFormulas/Financial.ts
 43index af38ac7..8d0f716 100644
 44--- a/src/RawFormulas/Financial.ts
 45+++ b/src/RawFormulas/Financial.ts
 46@@ -7,6 +7,10 @@ import {
 47   NumError,
 48   DivZeroError
 49 } from "../Errors"
 50+import {
 51+  YEARFRAC
 52+} from "./Date";
 53+
 54 
 55 /**
 56  * Calculates the depreciation of an asset for a specified period using the double-declining balance method.
 57@@ -358,7 +362,51 @@ var CUMIPMT = function (...values) : number {
 58   return interest;
 59 };
 60 
 61+/**
 62+ * Calculates the accrued interest of a security that has periodic payments.
 63+ *
 64+ * Links:
 65+ * * https://quant.stackexchange.com/questions/7040/whats-the-algorithm-behind-excels-accrint
 66+ *
 67+ * * https://support.office.com/en-us/article/ACCRINT-function-fe45d089-6722-4fb3-9379-e1f911d8dc74
 68+ *
 69+ * * https://quant.stackexchange.com/questions/7040/whats-the-algorithm-behind-excels-accrint
 70+ * @param values[0] issue - The date the security was initially issued.
 71+ * @param values[1] first_payment - The first date interest will be paid.
 72+ * @param values[2] settlement - The settlement date of the security, the date after issuance when the security is
 73+ * delivered to the buyer. Is the maturity date of the security if it is held until maturity rather than sold.
 74+ * @param values[3] rate - The annualized rate of interest.
 75+ * @param values[4] redemption - The redemption amount per 100 face value, or par.
 76+ * @param values[5] frequency - The number of interest or coupon payments per year (1, 2, or 4).
 77+ * @param values[6] day_count_convention - [ OPTIONAL - 0 by default ] - An indicator of what day count method to use.
 78+ * 0 indicates US (NASD) 30/360 - This assumes 30 day months and 360 day years as per the National Association of
 79+ * Securities Dealers standard, and performs specific adjustments to entered dates which fall at the end of months.
 80+ * 1 indicates Actual/Actual - This calculates based upon the actual number of days between the specified dates, and the
 81+ * actual number of days in the intervening years. Used for US Treasury Bonds and Bills, but also the most relevant for
 82+ * non-financial use. 2 indicates Actual/360 - This calculates based on the actual number of days between the speficied
 83+ * dates, but assumes a 360 day year. 3 indicates Actual/365 - This calculates based on the actual number of days
 84+ * between the specified dates, but assumes a 365 day year. 4 indicates European 30/360 - Similar to 0, this calculates
 85+ * based on a 30 day month and 360 day year, but adjusts end-of-month dates according to European financial conventions.
 86+ * @returns {number}
 87+ * @constructor
 88+ */
 89+var ACCRINT = function (...values) {
 90+  ArgsChecker.checkLengthWithin(values, 6, 7);
 91+  var issue = TypeCaster.firstValueAsExcelDate(values[0]);
 92+  // firstPayment param is only here to check for errors for GS implementation.
 93+  var firstPayment = TypeCaster.firstValueAsExcelDate(values[1]);
 94+  var settlement = TypeCaster.firstValueAsExcelDate(values[2]);
 95+  var rate = TypeCaster.firstValueAsNumber(values[3]);
 96+  var redemption = TypeCaster.firstValueAsNumber(values[4]);// "par"
 97+  // The frequency parameter also does not affect the resulting value of the formula.
 98+  var frequency = TypeCaster.firstValueAsNumber(values[5]);
 99+  var dayCountConvention = values.length === 7 ? TypeCaster.firstValueAsNumber(values[6]) : 1;// "basis"
100+  var factor = YEARFRAC(issue, settlement, dayCountConvention);
101+  return redemption * rate * factor;
102+};
103+
104 export {
105+  ACCRINT,
106   CUMPRINC,
107   CUMIPMT,
108   DB,
109diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
110index 2c6e794..935efce 100644
111--- a/src/RawFormulas/RawFormulas.ts
112+++ b/src/RawFormulas/RawFormulas.ts
113@@ -71,6 +71,7 @@ import {
114   DELTA
115 } from "./Engineering";
116 import {
117+  ACCRINT,
118   CUMPRINC,
119   CUMIPMT,
120   DB,
121@@ -135,7 +136,6 @@ import {
122   WORKDAY$INTL
123 } from "./Date"
124 
125-var ACCRINT = Formula["ACCRINT"];
126 var CONVERT = Formula["CONVERT"];
127 
128 
129diff --git a/tests/DateFormulasTest.ts b/tests/DateFormulasTest.ts
130index 1f07fed..2c2cd00 100644
131--- a/tests/DateFormulasTest.ts
132+++ b/tests/DateFormulasTest.ts
133@@ -379,6 +379,27 @@ catchAndAssertEquals(function() {
134 
135 
136 // Test YEARFRAC
137+assertEquals(YEARFRAC(1, 1461, 2), 4.055555555555555);
138+assertEquals(YEARFRAC(0, 365, 0), 1);
139+assertEquals(YEARFRAC(0, 365, 1), 1);
140+assertEquals(YEARFRAC(0, 365, 2), 1.0138888888888888);
141+assertEquals(YEARFRAC(0, 365, 3), 1);
142+assertEquals(YEARFRAC(0, 365, 4), 1);
143+assertEquals(YEARFRAC(0, 1000, 0), 2.738888888888889);
144+assertEquals(YEARFRAC(0, 1000, 1), 2.73972602739726);
145+assertEquals(YEARFRAC(0, 1000, 2), 2.7777777777777777);
146+assertEquals(YEARFRAC(0, 1000, 3), 2.73972602739726);
147+assertEquals(YEARFRAC(0, 1000, 4), 2.738888888888889);
148+assertEquals(YEARFRAC(10000, 20000, 0), 27.375);
149+assertEquals(YEARFRAC(10000, 20000, 1), 27.378507871321013); // gs: 27.37808219, ms: 27.37850787
150+assertEquals(YEARFRAC(10000, 20000, 2), 27.77777777777778);
151+assertEquals(YEARFRAC(10000, 20000, 3), 27.397260273972602);
152+assertEquals(YEARFRAC(10000, 20000, 4), 27.375);
153+assertEquals(YEARFRAC(100000, 200000, 0), 273.7944444444444);
154+assertEquals(YEARFRAC(100000, 200000, 1), 273.7925747453729); // gs: 273.7917808, ms: 273.7925747
155+assertEquals(YEARFRAC(100000, 200000, 2), 277.77777777777777);
156+assertEquals(YEARFRAC(100000, 200000, 3), 273.972602739726);
157+assertEquals(YEARFRAC(100000, 200000, 4), 273.7944444444444);
158 assertEquals(YEARFRAC("1969-7-6", "1988-7-4", 0), 18.994444444444444);
159 assertEquals(YEARFRAC("1969-7-6", "1988-7-22", 0), 19.044444444444444);
160 assertEquals(YEARFRAC("1992-1-6", "2191-7-22", 0), 199.544444444444444);
161diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
162index 3cc763d..10793c2 100644
163--- a/tests/FormulasTest.ts
164+++ b/tests/FormulasTest.ts
165@@ -7,7 +7,7 @@ import { ABS, ACCRINT, ACOS, ACOSH, ACOTH, AND, ARABIC, ASIN, ASINH, ATAN, ATAN2
166     EFFECT, ERF, ERFC, EVEN, EXACT, EXPONDIST, FINV, FALSE, FLOOR, __COMPLEX, FISHER, FISHERINV, IF,
167     INT, ISEVEN, ISODD, LN, LOG, LOG10, MAX, MAXA, MEDIAN, MIN, MINA, MOD, NOT, TRUE, ODD, OR,
168     POWER, ROUND, ROUNDDOWN, ROUNDUP, SIN, SINH, SPLIT, SQRT, SQRTPI, SUM, SUMIF, SUMPRODUCT, RADIANS,
169-    SUMSQ, SUMX2MY2, SUMX2PY2, TAN, TANH, TRUNC, XOR } from "../src/RawFormulas/RawFormulas"
170+    SUMSQ, SUMX2MY2, SUMX2PY2, TAN, TANH, TRUNC, XOR, DATE } from "../src/RawFormulas/RawFormulas"
171 import * as ERRORS from "../src/Errors"
172 import {assertEquals, assertArrayEquals} from "./utils/Asserts"
173 
174@@ -41,8 +41,20 @@ catchAndAssertEquals(function() {
175 
176 
177 // Test ACCRINT
178-// TODO: This formula doesn't work properly under some circumstances.
179-// assertEquals(ACCRINT(DATE(2011, 1, 1), DATE(2011, 2, 1), DATE(2014, 7, 1), 0.1, 1000, 1, 0), 350);
180+assertEquals(ACCRINT(DATE(2000, 1, 1), DATE(2000, 2, 1), DATE(2002, 12, 31), 0.05, 100, 4), 14.98631386861314);
181+assertEquals(ACCRINT(DATE(2011, 1, 1), DATE(2011, 2, 1), DATE(2014, 7, 1), 0.1, 1000, 1, 0), 350);
182+assertEquals(ACCRINT(DATE(2001, 1, 1), DATE(2011, 2, 1), DATE(2014, 7, 1), 0.1, 1000, 2, 1), 1349.6186192059456);
183+assertEquals(ACCRINT(39508, 39691, 39569, 0.1, 1000, 2, 0), 16.666666666666664);
184+assertEquals(ACCRINT(10000, 1, 20000, 0.1, 1000, 4, 0), 2737.5);
185+assertEquals(ACCRINT(10000, 1, 20000, 0.1, 1000, 4, 1), 2737.8507871321012); // ms: 2787.087912 (1.76% err), gs: 2737.637363 (0.007% err)
186+assertEquals(ACCRINT(10000, 1, 20000, 0.1, 1000, 4, 2), 2777.777777777778); // ms, gs: 2737.777778 (1.46% err)
187+assertEquals(ACCRINT(10000, 1, 20000, 0.1, 1000, 4, 3), 2739.72602739726); //ms, gs: 2737.60274 (0.077% err)
188+assertEquals(ACCRINT(10000, 1, 20000, 0.1, 1000, 4, 4), 2737.5);
189+assertEquals(ACCRINT(1, 2, 1461, 0.1, 1000, 1, 0), 400);
190+assertEquals(ACCRINT(1, 2, 1461, 0.1, 1000, 1, 1), 400);
191+assertEquals(ACCRINT(1, 2, 1461, 0.1, 1000, 1, 2), 405.55555555555554); // gs: 400
192+assertEquals(ACCRINT(1, 2, 1461, 0.1, 1000, 1, 3), 400); // gs: 399.6575342
193+assertEquals(ACCRINT(1, 2, 1461, 0.1, 1000, 1, 4), 400);
194 
195 
196 // Test ACOS