spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
Added Formulas.CUMIPMT
author
Ben Vogt <[email protected]>
date
2017-02-24 03:13:33
stats
3 file(s) changed, 126 insertions(+), 32 deletions(-)
files
src/RawFormulas/Financial.ts
src/RawFormulas/RawFormulas.ts
tests/FormulasTest.ts
  1diff --git a/src/RawFormulas/Financial.ts b/src/RawFormulas/Financial.ts
  2index 6338c4e..e9131f8 100644
  3--- a/src/RawFormulas/Financial.ts
  4+++ b/src/RawFormulas/Financial.ts
  5@@ -212,6 +212,38 @@ var EFFECT = function (...values) : number {
  6   return Math.pow(1 + rate / periods, periods) - 1;
  7 };
  8 
  9+// TODO: Convert to real formula PMT.
 10+function pmt(rate, periods, present, future, type) {
 11+  var result;
 12+  if (rate === 0) {
 13+    result = (present + future) / periods;
 14+  } else {
 15+    var term = Math.pow(1 + rate, periods);
 16+    if (type) {
 17+      result = (future * rate / (term - 1) + present * rate / (1 - 1 / term)) / (1 + rate);
 18+    } else {
 19+      result = future * rate / (term - 1) + present * rate / (1 - 1 / term);
 20+    }
 21+  }
 22+  return -result;
 23+}
 24+
 25+// TODO: Convert to real formula FV
 26+function fv(rate, periods, payment, value, type) {
 27+  var result;
 28+  if (rate === 0) {
 29+    result = value + payment * periods;
 30+  } else {
 31+    var term = Math.pow(1 + rate, periods);
 32+    if (type) {
 33+      result = value * term + payment * (1 + rate) * (term - 1.0) / rate;
 34+    } else {
 35+      result = value * term + payment * (term - 1) / rate;
 36+    }
 37+  }
 38+  return -result;
 39+}
 40+
 41 /**
 42  * Calculates the cumulative principal paid over a range of payment periods for an investment based on constant-amount
 43  * periodic payments and a constant interest rate.
 44@@ -227,36 +259,6 @@ var EFFECT = function (...values) : number {
 45  * @constructor
 46  */
 47 var CUMPRINC = function (...values) : number {
 48-  function pmt(rate, periods, present, future, type) {
 49-    var result;
 50-    if (rate === 0) {
 51-      result = (present + future) / periods;
 52-    } else {
 53-      var term = Math.pow(1 + rate, periods);
 54-      if (type) {
 55-        result = (future * rate / (term - 1) + present * rate / (1 - 1 / term)) / (1 + rate);
 56-      } else {
 57-        result = future * rate / (term - 1) + present * rate / (1 - 1 / term);
 58-      }
 59-    }
 60-    return -result;
 61-  }
 62-
 63-  function fv(rate, periods, payment, value, type) {
 64-    var result;
 65-    if (rate === 0) {
 66-      result = value + payment * periods;
 67-    } else {
 68-      var term = Math.pow(1 + rate, periods);
 69-      if (type) {
 70-        result = value * term + payment * (1 + rate) * (term - 1.0) / rate;
 71-      } else {
 72-        result = value * term + payment * (term - 1) / rate;
 73-      }
 74-    }
 75-    return -result;
 76-  }
 77-
 78   ArgsChecker.checkLength(values, 6);
 79   var rate = TypeCaster.firstValueAsNumber(values[0]);
 80   var periods = TypeCaster.firstValueAsNumber(values[1]);
 81@@ -294,8 +296,62 @@ var CUMPRINC = function (...values) : number {
 82   return principal;
 83 };
 84 
 85+/**
 86+ * Calculates the cumulative interest over a range of payment periods for an investment based on constant-amount
 87+ * periodic payments and a constant interest rate.
 88+ * @param values[0] rate - The interest rate.
 89+ * @param values[1] number_of_periods - The number of payments to be made.
 90+ * @param values[2] present_value - The current value of the annuity.
 91+ * @param values[3] first_period - The number of the payment period to begin the cumulative calculation, must be greater
 92+ * than or equal to 1.
 93+ * @param values[4] last_period - The number of the payment period to end the cumulative calculation, must be greater
 94+ * than first_period.
 95+ * @param values[5] end_or_beginning - Whether payments are due at the end (0) or beginning (1) of each period.
 96+ * @returns {number} cumulative interest
 97+ * @constructor
 98+ */
 99+var CUMIPMT = function (...values) : number {
100+  ArgsChecker.checkLength(values, 6);
101+  var rate = TypeCaster.firstValueAsNumber(values[0]);
102+  var periods = TypeCaster.firstValueAsNumber(values[1]);
103+  var value = TypeCaster.firstValueAsNumber(values[2]);
104+  var start = TypeCaster.firstValueAsNumber(values[3]);
105+  if (start < 1) {
106+    throw new CellError(ERRORS.NUM_ERROR, "Function CUMPRINC parameter 4 value is " + start + ". It should be greater than or equal to 1.");
107+  }
108+  var end = TypeCaster.firstValueAsNumber(values[4]);
109+  if (end < 1) {
110+    throw new CellError(ERRORS.NUM_ERROR, "Function CUMPRINC parameter 5 value is " + end + ". It should be greater than or equal to 1.");
111+  }
112+  if (end < start) {
113+    throw new CellError(ERRORS.NUM_ERROR, "Function CUMPRINC parameter 5 value is " + end + ". It should be greater than or equal to " + start + ".");
114+  }
115+  var type = TypeCaster.firstValueAsBoolean(values[5]);
116+
117+  var payment = pmt(rate, periods, value, 0, type);
118+  var interest = 0;
119+  if (start === 1) {
120+    if (!type) {
121+      interest = -value;
122+      start++;
123+    } else {
124+      start++;
125+    }
126+  }
127+  for (var i = start; i <= end; i++) {
128+    if (type) {
129+      interest += fv(rate, i - 2, payment, value, 1) - payment;
130+    } else {
131+      interest += fv(rate, i - 1, payment, value, 0);
132+    }
133+  }
134+  interest *= rate;
135+  return interest;
136+};
137+
138 export {
139   CUMPRINC,
140+  CUMIPMT,
141   DB,
142   DDB,
143   DOLLAR,
144diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
145index 2427a1f..9b44602 100644
146--- a/src/RawFormulas/RawFormulas.ts
147+++ b/src/RawFormulas/RawFormulas.ts
148@@ -74,6 +74,7 @@ import {
149 } from "./Engineering";
150 import {
151   CUMPRINC,
152+  CUMIPMT,
153   DB,
154   DDB,
155   DOLLAR,
156@@ -124,7 +125,6 @@ import * as ERRORS from "../Errors"
157 
158 var ACCRINT = Formula["ACCRINT"];
159 var CONVERT = Formula["CONVERT"];
160-var CUMIPMT = Formula["CUMIPMT"];
161 var DATE = Formula["DATE"];
162 var DATEVALUE = function (dateString: string) : Date {
163   return new Date(dateString);
164diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
165index 8f86bee..d113d5d 100644
166--- a/tests/FormulasTest.ts
167+++ b/tests/FormulasTest.ts
168@@ -689,6 +689,7 @@ catchAndAssertEquals(function() {
169   COUNTIFS([1, 5, 10, 20], ">4", [0, 0], "=1");
170 }, ERRORS.VALUE_ERROR);
171 
172+
173 // Test COUNTUNIQUE
174 assertEquals(COUNTUNIQUE([1, 1, 10]), 2);
175 assertEquals(COUNTUNIQUE(["1", 1, 10]), 3);
176@@ -705,6 +706,30 @@ catchAndAssertEquals(function() {
177 
178 // Test CUMIPMT
179 assertEquals(CUMIPMT(0.12, 12, 100, 1, 5, 0), -54.39423242396348);
180+assertEquals(CUMIPMT(0.12, 12, 100, 1, 5, false), -54.39423242396348);
181+assertEquals(CUMIPMT(0.12, 12, 100, 1, 5, true), -37.851993235681675);
182+assertEquals(CUMIPMT(0.12, 12, 100, 1, 5, 1), -37.851993235681675);
183+assertEquals(CUMIPMT(0.12, 12, 100, 2, 6, 1), -45.74583201714228);
184+assertEquals(CUMIPMT(0.12, 12, 100, 2, 6, true), -45.74583201714228);
185+assertEquals(CUMIPMT([0.12], ["12"], [100, "str"], "1", 5, 0), -54.39423242396348);
186+catchAndAssertEquals(function() {
187+  CUMIPMT(0.12, 12, 100, 1, 5, []);
188+}, ERRORS.REF_ERROR);
189+catchAndAssertEquals(function() {
190+  CUMIPMT(0.12, 12, 100, 0, 5, false);
191+}, ERRORS.NUM_ERROR);
192+catchAndAssertEquals(function() {
193+  CUMIPMT(0.12, 12, 100, 3, 1, false);
194+}, ERRORS.NUM_ERROR);
195+catchAndAssertEquals(function() {
196+  CUMIPMT();
197+}, ERRORS.NA_ERROR);
198+catchAndAssertEquals(function() {
199+  CUMIPMT(0.12, 12, 100, 1, 5, true, 55);
200+}, ERRORS.NA_ERROR);
201+catchAndAssertEquals(function() {
202+  CUMIPMT(0.12, 12, 100, 1, 5);
203+}, ERRORS.NA_ERROR);
204 
205 
206 // Test CUMPRINC
207@@ -732,7 +757,6 @@ catchAndAssertEquals(function() {
208 }, ERRORS.NA_ERROR);
209 
210 
211-
212 assertEqualsDates(DATE(1992, 6, 24), new Date("6/24/1992"));
213 assertEqualsDates(DATE(1992, 13, 24), new Date("1/24/1993"));
214 assertEqualsDates(DATE(1992, 6, 44), new Date("7/14/1992"));