commit
message
Added Formulas.CUMPRINC
author
Ben Vogt <[email protected]>
date
2017-02-24 02:37:18
stats
4 file(s) changed,
110 insertions(+),
2 deletions(-)
files
src/RawFormulas/Financial.ts
src/RawFormulas/RawFormulas.ts
src/RawFormulas/Statistical.ts
tests/FormulasTest.ts
1diff --git a/src/RawFormulas/Financial.ts b/src/RawFormulas/Financial.ts
2index de49da0..6338c4e 100644
3--- a/src/RawFormulas/Financial.ts
4+++ b/src/RawFormulas/Financial.ts
5@@ -212,7 +212,90 @@ var EFFECT = function (...values) : number {
6 return Math.pow(1 + rate / periods, periods) - 1;
7 };
8
9+/**
10+ * Calculates the cumulative principal paid over a range of payment periods for an investment based on constant-amount
11+ * periodic payments and a constant interest rate.
12+ * @param values[0] rate - The interest rate.
13+ * @param values[1] number_of_periods - The number of payments to be made.
14+ * @param values[2] present_value - The current value of the annuity.
15+ * @param values[3] first_period - The number of the payment period to begin the cumulative calculation. must be greater
16+ * than or equal to 1.
17+ * @param values[4] last_period - The number of the payment period to end the cumulative calculation, must be greater
18+ * than first_period.
19+ * @param values[5] end_or_beginning - Whether payments are due at the end (0) or beginning (1) of each period
20+ * @returns {number} cumulative principal
21+ * @constructor
22+ */
23+var CUMPRINC = function (...values) : number {
24+ function pmt(rate, periods, present, future, type) {
25+ var result;
26+ if (rate === 0) {
27+ result = (present + future) / periods;
28+ } else {
29+ var term = Math.pow(1 + rate, periods);
30+ if (type) {
31+ result = (future * rate / (term - 1) + present * rate / (1 - 1 / term)) / (1 + rate);
32+ } else {
33+ result = future * rate / (term - 1) + present * rate / (1 - 1 / term);
34+ }
35+ }
36+ return -result;
37+ }
38+
39+ function fv(rate, periods, payment, value, type) {
40+ var result;
41+ if (rate === 0) {
42+ result = value + payment * periods;
43+ } else {
44+ var term = Math.pow(1 + rate, periods);
45+ if (type) {
46+ result = value * term + payment * (1 + rate) * (term - 1.0) / rate;
47+ } else {
48+ result = value * term + payment * (term - 1) / rate;
49+ }
50+ }
51+ return -result;
52+ }
53+
54+ ArgsChecker.checkLength(values, 6);
55+ var rate = TypeCaster.firstValueAsNumber(values[0]);
56+ var periods = TypeCaster.firstValueAsNumber(values[1]);
57+ var value = TypeCaster.firstValueAsNumber(values[2]);
58+ var start = TypeCaster.firstValueAsNumber(values[3]);
59+ if (start < 1) {
60+ throw new CellError(ERRORS.NUM_ERROR, "Function CUMPRINC parameter 4 value is " + start + ". It should be greater than or equal to 1.");
61+ }
62+ var end = TypeCaster.firstValueAsNumber(values[4]);
63+ if (end < 1) {
64+ throw new CellError(ERRORS.NUM_ERROR, "Function CUMPRINC parameter 5 value is " + end + ". It should be greater than or equal to 1.");
65+ }
66+ if (end < start) {
67+ throw new CellError(ERRORS.NUM_ERROR, "Function CUMPRINC parameter 5 value is " + end + ". It should be greater than or equal to " + start + ".");
68+ }
69+ var type = TypeCaster.firstValueAsBoolean(values[5]);
70+
71+ var payment = pmt(rate, periods, value, 0, type);
72+ var principal = 0;
73+ if (start === 1) {
74+ if (type) {
75+ principal = payment;
76+ } else {
77+ principal = payment + value * rate;
78+ }
79+ start++;
80+ }
81+ for (var i = start; i <= end; i++) {
82+ if (type) {
83+ principal += payment - (fv(rate, i - 2, payment, value, 1) - payment) * rate;
84+ } else {
85+ principal += payment - fv(rate, i - 1, payment, value, 0) * rate;
86+ }
87+ }
88+ return principal;
89+};
90+
91 export {
92+ CUMPRINC,
93 DB,
94 DDB,
95 DOLLAR,
96diff --git a/src/RawFormulas/RawFormulas.ts b/src/RawFormulas/RawFormulas.ts
97index 4481168..2427a1f 100644
98--- a/src/RawFormulas/RawFormulas.ts
99+++ b/src/RawFormulas/RawFormulas.ts
100@@ -73,6 +73,7 @@ import {
101 DELTA
102 } from "./Engineering";
103 import {
104+ CUMPRINC,
105 DB,
106 DDB,
107 DOLLAR,
108@@ -124,7 +125,6 @@ import * as ERRORS from "../Errors"
109 var ACCRINT = Formula["ACCRINT"];
110 var CONVERT = Formula["CONVERT"];
111 var CUMIPMT = Formula["CUMIPMT"];
112-var CUMPRINC = Formula["CUMPRINC"];
113 var DATE = Formula["DATE"];
114 var DATEVALUE = function (dateString: string) : Date {
115 return new Date(dateString);
116diff --git a/src/RawFormulas/Statistical.ts b/src/RawFormulas/Statistical.ts
117index 15026f4..b876e6a 100644
118--- a/src/RawFormulas/Statistical.ts
119+++ b/src/RawFormulas/Statistical.ts
120@@ -777,7 +777,6 @@ var COUNTA = function (...values) : number {
121 return count;
122 };
123
124-
125 export {
126 AVERAGE,
127 AVERAGEA,
128diff --git a/tests/FormulasTest.ts b/tests/FormulasTest.ts
129index c89eceb..8f86bee 100644
130--- a/tests/FormulasTest.ts
131+++ b/tests/FormulasTest.ts
132@@ -703,9 +703,35 @@ catchAndAssertEquals(function() {
133 }, ERRORS.NA_ERROR);
134
135
136+// Test CUMIPMT
137 assertEquals(CUMIPMT(0.12, 12, 100, 1, 5, 0), -54.39423242396348);
138
139+
140+// Test CUMPRINC
141+assertEquals(CUMPRINC(0.12, 12, 100, 1, 5, false), -26.324171373034403);
142 assertEquals(CUMPRINC(0.12, 12, 100, 1, 5, 0), -26.324171373034403);
143+assertEquals(CUMPRINC(0.12, 12, 100, 1, 5, true), -34.21801015449499);
144+assertEquals(CUMPRINC(0.12, 12, 100, 1, 5, -11), -34.21801015449499);
145+catchAndAssertEquals(function() {
146+ CUMPRINC(0.12, 12, 100, 1, 5, []);
147+}, ERRORS.REF_ERROR);
148+catchAndAssertEquals(function() {
149+ CUMPRINC(0.12, 12, 100, 0, 5, false);
150+}, ERRORS.NUM_ERROR);
151+catchAndAssertEquals(function() {
152+ CUMPRINC(0.12, 12, 100, 3, 1, false);
153+}, ERRORS.NUM_ERROR);
154+catchAndAssertEquals(function() {
155+ CUMPRINC();
156+}, ERRORS.NA_ERROR);
157+catchAndAssertEquals(function() {
158+ CUMPRINC(0.12, 12, 100, 1, 5, true, 55);
159+}, ERRORS.NA_ERROR);
160+catchAndAssertEquals(function() {
161+ CUMPRINC(0.12, 12, 100, 1, 5);
162+}, ERRORS.NA_ERROR);
163+
164+
165
166 assertEqualsDates(DATE(1992, 6, 24), new Date("6/24/1992"));
167 assertEqualsDates(DATE(1992, 13, 24), new Date("1/24/1993"));