commit
message
[Financial.RATE] formula added and tested
author
Ben Vogt <[email protected]>
date
2017-10-06 00:35:02
stats
8 file(s) changed,
195 insertions(+),
7 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 44a9ed9..a7ae0bb 100644
3--- a/DOCS.md
4+++ b/DOCS.md
5@@ -614,6 +614,19 @@
6 @param type - [OPTIONAL defaults to 0] Defines whether the payment is due at the beginning (1) or the end (0) of a period.
7 @constructor
8 ```
9+
10+### RATE
11+
12+```
13+ Returns the constant interest rate per period of an annuity.
14+@param periods - The total number of periods, during which payments are made (payment period).
15+@param paymentPerPeriod - The constant payment (annuity) paid during each period.
16+@param presentValue - The cash value in the sequence of payments
17+@param futureValue - [OPTIONAL defaults to 0] The future value, which is reached at the end of the periodic payments.
18+@param beginningOrEnd - [OPTIONAL defaults to 0] Defines whether the payment is due at the beginning (1) or the end (0) of a period.
19+@param guessRate - [OPTIONAL] - Determines the estimated value of the interest with iterative calculation.
20+@constructor
21+```
22 ## Info
23
24
25diff --git a/TODO.md b/TODO.md
26index fe68aca..d31123a 100644
27--- a/TODO.md
28+++ b/TODO.md
29@@ -88,6 +88,5 @@ Many of these formulas can be written by allowing the Sheet and Parser to return
30 * PRICE
31 * PRICEDISC
32 * PRICEMAT
33-* RATE
34 * RECEIVED
35 * YIELD
36diff --git a/dist/Formulas/AllFormulas.js b/dist/Formulas/AllFormulas.js
37index fbb5f3d..56af867 100644
38--- a/dist/Formulas/AllFormulas.js
39+++ b/dist/Formulas/AllFormulas.js
40@@ -148,6 +148,7 @@ exports.FV = Financial_1.FV;
41 exports.PPMT = Financial_1.PPMT;
42 exports.FVSCHEDULE = Financial_1.FVSCHEDULE;
43 exports.PV = Financial_1.PV;
44+exports.RATE = Financial_1.RATE;
45 var Statistical_1 = require("./Statistical");
46 exports.AVERAGE = Statistical_1.AVERAGE;
47 exports.AVERAGEA = Statistical_1.AVERAGEA;
48diff --git a/dist/Formulas/Financial.js b/dist/Formulas/Financial.js
49index 2018ab1..ebb4a67 100644
50--- a/dist/Formulas/Financial.js
51+++ b/dist/Formulas/Financial.js
52@@ -752,3 +752,71 @@ var PV = function (rate, periods, paymentPerPeriod, future, type) {
53 }
54 };
55 exports.PV = PV;
56+/**
57+ * Returns the constant interest rate per period of an annuity.
58+ * @param periods - The total number of periods, during which payments are made (payment period).
59+ * @param paymentPerPeriod - The constant payment (annuity) paid during each period.
60+ * @param presentValue - The cash value in the sequence of payments
61+ * @param futureValue - [OPTIONAL defaults to 0] The future value, which is reached at the end of the periodic payments.
62+ * @param beginningOrEnd - [OPTIONAL defaults to 0] Defines whether the payment is due at the beginning (1) or the end
63+ * (0) of a period.
64+ * @param guessRate - [OPTIONAL] - Determines the estimated value of the interest with iterative
65+ * calculation.
66+ * @constructor
67+ */
68+var RATE = function (periods, paymentPerPeriod, presentValue, futureValue, beginningOrEnd, guessRate) {
69+ ArgsChecker_1.ArgsChecker.checkLengthWithin(arguments, 3, 6, "RATE");
70+ periods = TypeConverter_1.TypeConverter.firstValueAsNumber(periods);
71+ if (periods < 1) {
72+ throw new Errors_1.NumError("Function RATE parameter 1 value is" + periods + ", but it should be greater than 0.");
73+ }
74+ paymentPerPeriod = TypeConverter_1.TypeConverter.firstValueAsNumber(paymentPerPeriod);
75+ presentValue = TypeConverter_1.TypeConverter.firstValueAsNumber(presentValue);
76+ futureValue = MoreUtils_1.isDefined(futureValue) ? TypeConverter_1.TypeConverter.firstValueAsNumber(futureValue) : 0;
77+ beginningOrEnd = MoreUtils_1.isDefined(beginningOrEnd) ? TypeConverter_1.TypeConverter.firstValueAsNumber(beginningOrEnd) : 0;
78+ guessRate = MoreUtils_1.isDefined(guessRate) ? TypeConverter_1.TypeConverter.firstValueAsNumber(guessRate) : 0.1;
79+ // Sets the limits for possible guesses to any
80+ // number between 0% and 100%
81+ var lowLimit = 0;
82+ var highLimit = 1;
83+ var guess = guessRate;
84+ // Defines a tolerance of up to +/- 0.00005% of pmt, to accept
85+ // the solution as valid.
86+ var tolerance = Math.abs(0.00000005 * paymentPerPeriod);
87+ // Tries at most 40 times to find a solution within the tolerance.
88+ for (var i = 0; i < 40; i++) {
89+ // Resets the balance to the original pv.
90+ var balance = presentValue;
91+ // Calculates the balance at the end of the loan, based
92+ // on loan conditions.
93+ for (var j = 0; j < periods; j++) {
94+ if (beginningOrEnd == 0) {
95+ // Interests applied before payment
96+ balance = balance * (1 + guess) + paymentPerPeriod;
97+ }
98+ else {
99+ // Payments applied before insterests
100+ balance = (balance + paymentPerPeriod) * (1 + guess);
101+ }
102+ }
103+ // Returns the guess if balance is within tolerance. If not, adjusts
104+ // the limits and starts with a new guess.
105+ if (Math.abs(balance + futureValue) < tolerance) {
106+ return guess;
107+ }
108+ else if (balance + futureValue > 0) {
109+ // Sets a new highLimit knowing that
110+ // the current guess was too big.
111+ highLimit = guess;
112+ }
113+ else {
114+ // Sets a new lowLimit knowing that
115+ // the current guess was too small.
116+ lowLimit = guess;
117+ }
118+ // Calculates the new guess.
119+ guess = (highLimit + lowLimit) / 2;
120+ }
121+ throw new Errors_1.NumError("RATE attempted to complete but it was not able to.");
122+};
123+exports.RATE = RATE;
124diff --git a/src/Formulas/AllFormulas.ts b/src/Formulas/AllFormulas.ts
125index d70f881..0e7718f 100644
126--- a/src/Formulas/AllFormulas.ts
127+++ b/src/Formulas/AllFormulas.ts
128@@ -152,7 +152,8 @@ import {
129 FV,
130 PPMT,
131 FVSCHEDULE,
132- PV
133+ PV,
134+ RATE
135 } from "./Financial";
136 import {
137 AVERAGE,
138@@ -521,5 +522,6 @@ export {
139 ROMAN,
140 TEXT,
141 FVSCHEDULE,
142- PV
143+ PV,
144+ RATE
145 }
146\ No newline at end of file
147diff --git a/src/Formulas/Financial.ts b/src/Formulas/Financial.ts
148index 457457f..168c205 100644
149--- a/src/Formulas/Financial.ts
150+++ b/src/Formulas/Financial.ts
151@@ -13,7 +13,7 @@ import {
152 YEARFRAC
153 } from "./Date";
154 import {Filter} from "../Utilities/Filter";
155-import {isUndefined} from "../Utilities/MoreUtils";
156+import {isDefined, isUndefined} from "../Utilities/MoreUtils";
157
158
159 /**
160@@ -766,6 +766,78 @@ let PV = function (rate, periods, paymentPerPeriod, future?, type?) {
161 };
162
163
164+/**
165+ * Returns the constant interest rate per period of an annuity.
166+ * @param periods - The total number of periods, during which payments are made (payment period).
167+ * @param paymentPerPeriod - The constant payment (annuity) paid during each period.
168+ * @param presentValue - The cash value in the sequence of payments
169+ * @param futureValue - [OPTIONAL defaults to 0] The future value, which is reached at the end of the periodic payments.
170+ * @param beginningOrEnd - [OPTIONAL defaults to 0] Defines whether the payment is due at the beginning (1) or the end
171+ * (0) of a period.
172+ * @param guessRate - [OPTIONAL] - Determines the estimated value of the interest with iterative
173+ * calculation.
174+ * @constructor
175+ */
176+let RATE = function (periods, paymentPerPeriod, presentValue, futureValue?, beginningOrEnd?, guessRate?) {
177+ ArgsChecker.checkLengthWithin(arguments, 3, 6, "RATE");
178+ periods = TypeConverter.firstValueAsNumber(periods);
179+ if (periods < 1) {
180+ throw new NumError("Function RATE parameter 1 value is" + periods + ", but it should be greater than 0.");
181+ }
182+ paymentPerPeriod = TypeConverter.firstValueAsNumber(paymentPerPeriod);
183+ presentValue = TypeConverter.firstValueAsNumber(presentValue);
184+ futureValue = isDefined(futureValue) ? TypeConverter.firstValueAsNumber(futureValue) : 0;
185+ beginningOrEnd = isDefined(beginningOrEnd) ? TypeConverter.firstValueAsNumber(beginningOrEnd) : 0;
186+ guessRate = isDefined(guessRate) ? TypeConverter.firstValueAsNumber(guessRate) : 0.1;
187+
188+ // Sets the limits for possible guesses to any
189+ // number between 0% and 100%
190+ let lowLimit = 0;
191+ let highLimit = 1;
192+ let guess = guessRate;
193+
194+ // Defines a tolerance of up to +/- 0.00005% of pmt, to accept
195+ // the solution as valid.
196+ let tolerance = Math.abs(0.00000005 * paymentPerPeriod);
197+
198+ // Tries at most 40 times to find a solution within the tolerance.
199+ for (let i = 0; i < 40; i++) {
200+ // Resets the balance to the original pv.
201+ let balance = presentValue;
202+
203+ // Calculates the balance at the end of the loan, based
204+ // on loan conditions.
205+ for (let j = 0; j < periods; j++ ) {
206+ if (beginningOrEnd == 0) {
207+ // Interests applied before payment
208+ balance = balance * (1 + guess) + paymentPerPeriod;
209+ } else {
210+ // Payments applied before insterests
211+ balance = (balance + paymentPerPeriod) * (1 + guess);
212+ }
213+ }
214+
215+ // Returns the guess if balance is within tolerance. If not, adjusts
216+ // the limits and starts with a new guess.
217+ if (Math.abs(balance + futureValue) < tolerance) {
218+ return guess;
219+ } else if (balance + futureValue > 0) {
220+ // Sets a new highLimit knowing that
221+ // the current guess was too big.
222+ highLimit = guess;
223+ } else {
224+ // Sets a new lowLimit knowing that
225+ // the current guess was too small.
226+ lowLimit = guess;
227+ }
228+
229+ // Calculates the new guess.
230+ guess = (highLimit + lowLimit) / 2;
231+ }
232+ throw new NumError("RATE attempted to complete but it was not able to.");
233+};
234+
235+
236 export {
237 ACCRINT,
238 CUMPRINC,
239@@ -788,5 +860,6 @@ export {
240 FV,
241 PPMT,
242 FVSCHEDULE,
243- PV
244+ PV,
245+ RATE
246 }
247\ No newline at end of file
248diff --git a/tests/Formulas/FinancialTest.ts b/tests/Formulas/FinancialTest.ts
249index cd5ba32..10cede9 100644
250--- a/tests/Formulas/FinancialTest.ts
251+++ b/tests/Formulas/FinancialTest.ts
252@@ -20,7 +20,8 @@ import {
253 FV,
254 PPMT,
255 FVSCHEDULE,
256- PV
257+ PV,
258+ RATE
259 } from "../../src/Formulas/Financial";
260 import {
261 DATE
262@@ -500,4 +501,29 @@ test("PV", function() {
263 catchAndAssertEquals(function() {
264 PV.apply(this, [0, 1, 2, 3, 4, 5]);
265 }, ERRORS.NA_ERROR);
266+});
267+
268+
269+test("RATE", function() {
270+ assertEquals(RATE(12, -100, 400, 0, 0, 0.1), 0.22893307069316507);
271+ assertEquals(RATE(360, -665.3, 99000), 0.005916521358085446);
272+ assertEquals(RATE(360, -958.63, 192000), 0.0036458502960158515);
273+ assertEquals(RATE(180, -1302.96, 192000), 0.0022917255526408564);
274+ assertEquals(RATE(360, -889.19, 192000), 0.0031250616819306744);
275+ assertEquals(RATE(360, -1145.8, 240000), 0.003333353153720964);
276+ assertEquals(RATE(360, -665.3, 99000, 10), 0.00591642102735932);
277+ assertEquals(RATE(12, -100, 400, 100), 0.2225948800332845);
278+ assertEquals(RATE(360, -665.3, 99000, 10, 1), 0.005965913048930816);
279+ catchAndAssertEquals(function() {
280+ RATE(0, -100, 400, 10);
281+ }, ERRORS.NUM_ERROR);
282+ catchAndAssertEquals(function() {
283+ RATE(12, -100, 400, 1000000);
284+ }, ERRORS.NUM_ERROR);
285+ catchAndAssertEquals(function() {
286+ RATE.apply(this, [0, 1]);
287+ }, ERRORS.NA_ERROR);
288+ catchAndAssertEquals(function() {
289+ RATE.apply(this, [1, 2, 3, 4, 5, 6, 7]);
290+ }, ERRORS.NA_ERROR);
291 });
292\ No newline at end of file
293diff --git a/tests/SheetFormulaTest.ts b/tests/SheetFormulaTest.ts
294index 4bbb5ef..5cb1477 100644
295--- a/tests/SheetFormulaTest.ts
296+++ b/tests/SheetFormulaTest.ts
297@@ -1029,6 +1029,10 @@ test("Sheet PV", function(){
298 assertFormulaEquals('=PV(2, 12, 100)', -49.99990591617884);
299 });
300
301+test("Sheet RATE", function(){
302+ assertFormulaEquals('=RATE(12, -100, 400, 100)', 0.2225948800332845);
303+});
304+
305 test("Sheet parsing error", function(){
306 assertFormulaEqualsError('= 10e', PARSE_ERROR);
307 assertFormulaEqualsError('= SUM(', PARSE_ERROR);