spreadsheet
typeScript/javascript spreadsheet parser, with formulas.
git clone https://git.vogt.world/spreadsheet.git
Log | Files | README.md
← Commit log
commit
message
[IPMT] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-06-30 14:06:29
stats
8 file(s) changed, 141 insertions(+), 14 deletions(-)
files
DOCS.md
TODO.md
dist/Formulas/AllFormulas.js
dist/Formulas/Financial.js
src/Formulas/AllFormulas.ts
src/Formulas/Financial.ts
tests/Formulas/FinancialTest.ts
tests/SheetFormulaTest.ts
  1diff --git a/DOCS.md b/DOCS.md
  2index 49e50df..0fbc9b5 100644
  3--- a/DOCS.md
  4+++ b/DOCS.md
  5@@ -497,7 +497,7 @@
  6 
  7 ```
  8   Calculates the modified internal rate of return of a series of investments. 
  9-@param values - Range or values of payments. 
 10+@param values - Range or values of payments. Ignores text values. 
 11 @param financeRate - The rate of interest of the investments. 
 12 @param reinvestRate - The rate of interest of the reinvestment. 
 13 @returns {number} 
 14@@ -508,11 +508,25 @@
 15 
 16 ```
 17   Calculates the internal rate of return for an investment. The values represent cash flow values at regular intervals; at least one value must be negative (payments), and at least one value must be positive (income).  Relevant StackOverflow discussion: https:tackoverflow.comquestion15089151javascript-irr-internal-rate-of-return-formula-accuracy  
 18-@param values - Range containing values. 
 19+@param values - Range containing values. Ignores text values. 
 20 @param guess - [OPTIONAL] - The estimated value. Defaults to 0.01. 
 21 @returns {number} 
 22 @constructor
 23 ```
 24+
 25+### IPMT 
 26+
 27+```
 28+  Calculates the periodic amortization for an investment with regular payments and a constant interest rate. 
 29+@param rate - The periodic interest rate. 
 30+@param period - The period for which the compound interest is calculated. 
 31+@param periods - The total number of periods during which the annuity is paid. 
 32+@param present - The present cash value in sequence of payments. 
 33+@param future - [OPTIONAL] - The desired value (future value) at the end of the periods. 
 34+@param type - [OPTIONAL] - Defines whether the payment is due at the beginning (1) or the end (0) of a period. 
 35+@returns {number} 
 36+@constructor
 37+```
 38 ## Info
 39 
 40 
 41diff --git a/TODO.md b/TODO.md
 42index cc6ce41..fa9c4d7 100644
 43--- a/TODO.md
 44+++ b/TODO.md
 45@@ -140,7 +140,6 @@ For example 64 tbs to a qt.
 46 * FV - already written as a private function, needs to be re-written.
 47 * FVSCHEDULE
 48 * INTRATE
 49-* IPMT
 50 * PPMT - Similar to PMT, which is already written.
 51 * PRICE
 52 * PRICEDISC
 53diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
 54index 96cf996..27a7231 100644
 55--- a/dist/Formulas/AllFormulas.js
 56+++ b/dist/Formulas/AllFormulas.js
 57@@ -117,6 +117,7 @@ exports.NPER = Financial_1.NPER;
 58 exports.NOMINAL = Financial_1.NOMINAL;
 59 exports.MIRR = Financial_1.MIRR;
 60 exports.IRR = Financial_1.IRR;
 61+exports.IPMT = Financial_1.IPMT;
 62 var Statistical_1 = require("./Statistical");
 63 exports.AVERAGE = Statistical_1.AVERAGE;
 64 exports.AVERAGEA = Statistical_1.AVERAGEA;
 65diff --git a/dist/Formulas/Financial.js b/dist/Formulas/Financial.js
 66index 8a6278a..886a6f5 100644
 67--- a/dist/Formulas/Financial.js
 68+++ b/dist/Formulas/Financial.js
 69@@ -546,7 +546,7 @@ var NOMINAL = function (rate, periods) {
 70 exports.NOMINAL = NOMINAL;
 71 /**
 72  * Calculates the modified internal rate of return of a series of investments.
 73- * @param values - Range or values of payments.
 74+ * @param values - Range or values of payments. Ignores text values.
 75  * @param financeRate - The rate of interest of the investments.
 76  * @param reinvestRate - The rate of interest of the reinvestment.
 77  * @returns {number}
 78@@ -555,7 +555,9 @@ exports.NOMINAL = NOMINAL;
 79  */
 80 var MIRR = function (values, financeRate, reinvestRate) {
 81     ArgsChecker_1.ArgsChecker.checkLength(arguments, 3, "MIRR");
 82-    values = Filter_1.Filter.flattenAndThrow(values).map(function (value) {
 83+    values = Filter_1.Filter.flattenAndThrow(values).filter(function (value) {
 84+        return (typeof value !== "string");
 85+    }).map(function (value) {
 86         return TypeConverter_1.TypeConverter.valueToNumber(value);
 87     });
 88     var n = values.length;
 89@@ -583,14 +585,16 @@ exports.MIRR = MIRR;
 90  *
 91  * Relevant StackOverflow discussion: https://stackoverflow.com/questions/15089151/javascript-irr-internal-rate-of-return-formula-accuracy
 92  *
 93- * @param values - Range containing values.
 94+ * @param values - Range containing values. Ignores text values.
 95  * @param guess - [OPTIONAL] - The estimated value. Defaults to 0.01.
 96  * @returns {number}
 97  * @constructor
 98  */
 99 var IRR = function (values, guess) {
100     ArgsChecker_1.ArgsChecker.checkLengthWithin(arguments, 1, 2, "IRR");
101-    values = Filter_1.Filter.flattenAndThrow(values).map(function (value) {
102+    values = Filter_1.Filter.flattenAndThrow(values).filter(function (value) {
103+        return (typeof value !== "string");
104+    }).map(function (value) {
105         return TypeConverter_1.TypeConverter.valueToNumber(value);
106     });
107     guess = (guess === undefined) ? 0.1 : TypeConverter_1.TypeConverter.firstValueAsNumber(guess);
108@@ -615,3 +619,43 @@ var IRR = function (values, guess) {
109     return guess;
110 };
111 exports.IRR = IRR;
112+/**
113+ * Calculates the periodic amortization for an investment with regular payments and a constant interest rate.
114+ * @param rate - The periodic interest rate.
115+ * @param period - The period for which the compound interest is calculated.
116+ * @param periods - The total number of periods during which the annuity is paid.
117+ * @param present - The present cash value in sequence of payments.
118+ * @param future - [OPTIONAL] - The desired value (future value) at the end of the periods.
119+ * @param type - [OPTIONAL] - Defines whether the payment is due at the beginning (1) or the end (0) of a period.
120+ * @returns {number}
121+ * @constructor
122+ */
123+var IPMT = function (rate, period, periods, present, future, type) {
124+    ArgsChecker_1.ArgsChecker.checkLengthWithin(arguments, 4, 6, "IPMT");
125+    rate = TypeConverter_1.TypeConverter.firstValueAsNumber(rate);
126+    period = TypeConverter_1.TypeConverter.firstValueAsNumber(period);
127+    periods = TypeConverter_1.TypeConverter.firstValueAsNumber(periods);
128+    present = TypeConverter_1.TypeConverter.firstValueAsNumber(present);
129+    future = (typeof future === 'undefined') ? 0 : TypeConverter_1.TypeConverter.firstValueAsNumber(future);
130+    type = (typeof type === 'undefined') ? 0 : TypeConverter_1.TypeConverter.firstValueAsNumber(type);
131+    var payment = PMT(rate, periods, present, future, type);
132+    var interest;
133+    if (period === 1) {
134+        if (type === 1) {
135+            interest = 0;
136+        }
137+        else {
138+            interest = -present;
139+        }
140+    }
141+    else {
142+        if (type === 1) {
143+            interest = fv(rate, period - 2, payment, present, 1) - payment;
144+        }
145+        else {
146+            interest = fv(rate, period - 1, payment, present, 0);
147+        }
148+    }
149+    return interest * rate;
150+};
151+exports.IPMT = IPMT;
152diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
153index 90827c5..d16b401 100644
154--- a/src/Formulas/AllFormulas.ts
155+++ b/src/Formulas/AllFormulas.ts
156@@ -120,7 +120,8 @@ import {
157   NPER,
158   NOMINAL,
159   MIRR,
160-  IRR
161+  IRR,
162+  IPMT
163 } from "./Financial";
164 import {
165   AVERAGE,
166@@ -379,5 +380,6 @@ export {
167   NPER,
168   NOMINAL,
169   MIRR,
170-  IRR
171+  IRR,
172+  IPMT
173 }
174\ No newline at end of file
175diff --git a/src/Formulas/Financial.ts b/src/Formulas/Financial.ts
176index 0ccc0ac..91ebb05 100644
177--- a/src/Formulas/Financial.ts
178+++ b/src/Formulas/Financial.ts
179@@ -556,7 +556,7 @@ var NOMINAL =  function (rate, periods) {
180 
181 /**
182  * Calculates the modified internal rate of return of a series of investments.
183- * @param values - Range or values of payments.
184+ * @param values - Range or values of payments. Ignores text values.
185  * @param financeRate - The rate of interest of the investments.
186  * @param reinvestRate - The rate of interest of the reinvestment.
187  * @returns {number}
188@@ -565,7 +565,9 @@ var NOMINAL =  function (rate, periods) {
189  */
190 var MIRR = function (values, financeRate, reinvestRate) {
191   ArgsChecker.checkLength(arguments, 3, "MIRR");
192-  values =  Filter.flattenAndThrow(values).map(function (value) {
193+  values = Filter.flattenAndThrow(values).filter(function (value) {
194+    return (typeof value !== "string");
195+  }).map(function (value) {
196     return TypeConverter.valueToNumber(value);
197   });
198   var n = values.length;
199@@ -595,14 +597,16 @@ var MIRR = function (values, financeRate, reinvestRate) {
200  *
201  * Relevant StackOverflow discussion: https://stackoverflow.com/questions/15089151/javascript-irr-internal-rate-of-return-formula-accuracy
202  *
203- * @param values - Range containing values.
204+ * @param values - Range containing values. Ignores text values.
205  * @param guess - [OPTIONAL] - The estimated value. Defaults to 0.01.
206  * @returns {number}
207  * @constructor
208  */
209 var IRR =  function (values, guess?) {
210   ArgsChecker.checkLengthWithin(arguments, 1, 2, "IRR");
211-  values = Filter.flattenAndThrow(values).map(function (value) {
212+  values = Filter.flattenAndThrow(values).filter(function (value) {
213+    return (typeof value !== "string");
214+  }).map(function (value) {
215     return TypeConverter.valueToNumber(value);
216   });
217   guess = (guess === undefined) ? 0.1 : TypeConverter.firstValueAsNumber(guess);
218@@ -627,6 +631,44 @@ var IRR =  function (values, guess?) {
219   return guess;
220 };
221 
222+
223+/**
224+ * Calculates the periodic amortization for an investment with regular payments and a constant interest rate.
225+ * @param rate - The periodic interest rate.
226+ * @param period - The period for which the compound interest is calculated.
227+ * @param periods - The total number of periods during which the annuity is paid.
228+ * @param present - The present cash value in sequence of payments.
229+ * @param future - [OPTIONAL] - The desired value (future value) at the end of the periods.
230+ * @param type - [OPTIONAL] - Defines whether the payment is due at the beginning (1) or the end (0) of a period.
231+ * @returns {number}
232+ * @constructor
233+ */
234+var IPMT = function (rate, period, periods, present, future?, type?) {
235+  ArgsChecker.checkLengthWithin(arguments, 4, 6, "IPMT");
236+  rate = TypeConverter.firstValueAsNumber(rate);
237+  period = TypeConverter.firstValueAsNumber(period);
238+  periods = TypeConverter.firstValueAsNumber(periods);
239+  present = TypeConverter.firstValueAsNumber(present);
240+  future = (typeof future === 'undefined') ? 0 : TypeConverter.firstValueAsNumber(future);
241+  type = (typeof type === 'undefined') ? 0 : TypeConverter.firstValueAsNumber(type);
242+  var payment = PMT(rate, periods, present, future, type);
243+  var interest;
244+  if (period === 1) {
245+    if (type === 1) {
246+      interest = 0;
247+    } else {
248+      interest = -present;
249+    }
250+  } else {
251+    if (type === 1) {
252+      interest = fv(rate, period - 2, payment, present, 1) - payment;
253+    } else {
254+      interest = fv(rate, period - 1, payment, present, 0);
255+    }
256+  }
257+  return interest * rate;
258+};
259+
260 export {
261   ACCRINT,
262   CUMPRINC,
263@@ -644,5 +686,6 @@ export {
264   NPER,
265   NOMINAL,
266   MIRR,
267-  IRR
268+  IRR,
269+  IPMT
270 }
271\ No newline at end of file
272diff --git a/tests/Formulas/FinancialTest.ts b/tests/Formulas/FinancialTest.ts
273index 98fde6c..3cfe383 100644
274--- a/tests/Formulas/FinancialTest.ts
275+++ b/tests/Formulas/FinancialTest.ts
276@@ -15,7 +15,8 @@ import {
277   NPER,
278   NOMINAL,
279   MIRR,
280-  IRR
281+  IRR,
282+  IPMT
283 } from "../../src/Formulas/Financial";
284 import {
285   DATE
286@@ -379,6 +380,7 @@ test("MIRR", function() {
287 
288 
289 test("MIRR", function() {
290+  assertEquals(IRR([-1, 4, 10, 15, -22, 99, 44, 1000, -10, "ignore"]), 5.059102535247803);
291   assertEquals(IRR([-1, 4, 10, 15, -22, 99, 44, 1000, -10]), 5.059102535247803);
292   assertEquals(IRR([-1, 4, 10, 15, -22, 99, 44, 1000, -10], 0.1), 5.059102535247803);
293   assertEquals(IRR([-100, 100, 100, 100, 100, 100]), 0.9659482464194298);
294@@ -392,4 +394,20 @@ test("MIRR", function() {
295   catchAndAssertEquals(function() {
296     IRR.apply(this, [[100, 100, 100], 0.01, 4.4]);
297   }, ERRORS.NA_ERROR);
298+});
299+
300+
301+test("IPMT", function() {
302+  assertEquals(IPMT(0.025, 1, 66, 25000), -625);
303+  assertEquals(IPMT(0.025, 1, 66, 25000, 0, 0), -625);
304+  assertEquals(IPMT(0.025, 1, 66, 25000, 1, 1), 0);
305+  assertEquals(IPMT(0.025, 1, 66, 25000, 1, 0), -625);
306+  assertEquals(IPMT(100, 1, 66, 25000, 0), -2500000);
307+  assertEquals(IPMT(0.1, 4, 660, 4, 1), -0.4);
308+  catchAndAssertEquals(function() {
309+    IPMT.apply(this, [0.025, 1, 66]);
310+  }, ERRORS.NA_ERROR);
311+  catchAndAssertEquals(function() {
312+    IPMT.apply(this, [0.025, 1, 66, 25000, 0, 0, 1]);
313+  }, ERRORS.NA_ERROR);
314 });
315\ No newline at end of file
316diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
317index 100de34..3180fe6 100644
318--- a/tests/SheetFormulaTest.ts
319+++ b/tests/SheetFormulaTest.ts
320@@ -747,6 +747,10 @@ test("Sheet IRR", function(){
321   assertFormulaEquals('=IRR([-100, 100, 100])', 0.6180339809507132);
322 });
323 
324+test("Sheet IPMT", function(){
325+  assertFormulaEquals('=IPMT(0.025, 1, 66, 25000)', -625);
326+});
327+
328 test("Sheet *", function(){
329   assertFormulaEquals('= 10 * 10', 100);
330   assertFormulaEquals('= 10 * 0', 0);