Bug 65988: Rate function giving incorrect results

git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@1899668 13f79535-47bb-0310-9956-ffa450edef68
This commit is contained in:
Yegor Kozlov 2022-04-08 15:08:50 +00:00
parent 05e8a16543
commit 542900693e
2 changed files with 145 additions and 33 deletions

View File

@ -73,42 +73,49 @@ public class Rate implements Function {
return new NumberEval(rate);
}
private double calculateRate(double nper, double pmt, double pv, double fv, double type, double guess) {
//FROM MS http://office.microsoft.com/en-us/excel-help/rate-HP005209232.aspx
int FINANCIAL_MAX_ITERATIONS = 20;//Bet accuracy with 128
double FINANCIAL_PRECISION = 0.0000001;//1.0e-8
private static double _g_div_gp(double r, double n, double p, double x, double y, double w) {
double t1 = Math.pow(r+1, n);
double t2 = Math.pow(r+1, n-1);
return (y + t1*x + p*(t1 - 1)*(r*w + 1)/r) /
(n*t2*x - p*(t1 - 1)*(r*w + 1)/(Math.pow(r, 2) + n*p*t2*(r*w + 1)/r +
p*(t1 - 1)*w/r));
}
/**
* Compute the rate of interest per period.
*
* The implementation was ported from the NumPy library,
* see https://github.com/numpy/numpy-financial/blob/d02edfb65dcdf23bd571c2cded7fcd4a0528c6af/numpy_financial/_financial.py#L602
*
*
* @param nper Number of compounding periods
* @param pmt Payment
* @param pv Present Value
* @param fv Future value
* @param type When payments are due ('begin' (1) or 'end' (0))
* @param guess Starting guess for solving the rate of interest
* @return rate of interest per period or NaN if the solution didn't converge
*/
static double calculateRate(double nper, double pmt, double pv, double fv, double type, double guess){
double tol = 1e-8;
double maxiter = 100;
double rn = guess;
int iter = 0;
boolean close = false;
while (iter < maxiter && !close){
double rnp1 = rn - _g_div_gp(rn, nper, pmt, pv, fv, type);
double diff = Math.abs(rnp1 - rn);
close = diff < tol;
iter += 1;
rn = rnp1;
double y, y0, y1, x0, x1, f = 0, i;
double rate = guess;
if (Math.abs(rate) < FINANCIAL_PRECISION) {
y = pv * (1 + nper * rate) + pmt * (1 + rate * type) * nper + fv;
} else {
f = Math.pow(1 + rate, nper);
y = pv * f + pmt * (1 / rate + type) * (f - 1) + fv;
}
y0 = pv + pmt * nper + fv;
y1 = pv * f + pmt * (1 / rate + type) * (f - 1) + fv;
// find root by Newton secant method
i = x0 = 0.0;
x1 = rate;
while ((Math.abs(y0 - y1) > FINANCIAL_PRECISION) && (i < FINANCIAL_MAX_ITERATIONS)) {
rate = (y1 * x0 - y0 * x1) / (y1 - y0);
x0 = x1;
x1 = rate;
if (Math.abs(rate) < FINANCIAL_PRECISION) {
y = pv * (1 + nper * rate) + pmt * (1 + rate * type) * nper + fv;
} else {
f = Math.exp(nper * Math.log(1 + rate));
y = pv * f + pmt * (1 / rate + type) * (f - 1) + fv;
}
y0 = y1;
y1 = y;
++i;
if(!close)
return Double.NaN;
else {
return rn;
}
return rate;
}
/**

View File

@ -24,11 +24,13 @@ import org.apache.poi.hssf.usermodel.HSSFFormulaEvaluator;
import org.apache.poi.hssf.usermodel.HSSFRow;
import org.apache.poi.hssf.usermodel.HSSFSheet;
import org.apache.poi.hssf.usermodel.HSSFWorkbook;
import org.apache.poi.ss.usermodel.FormulaError;
import org.junit.jupiter.api.Disabled;
import org.junit.jupiter.api.Test;
import static org.apache.poi.ss.util.Utils.addRow;
import static org.apache.poi.ss.util.Utils.assertDouble;
import static org.apache.poi.ss.util.Utils.assertError;
/**
* Test cases for RATE()
@ -51,7 +53,110 @@ final class TestRate {
}
}
// https://wiki.documentfoundation.org/Documentation/Calc_Functions/RATE
@Test
void testLibreOfficeExample1() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = row.createCell(0);
assertDouble(fe, cell, "RATE(3,-10,900,1,0,0.5)", -0.7634, 0.0001);
}
}
// https://wiki.documentfoundation.org/Documentation/Calc_Functions/RATE
@Test
void testLibreOfficeExample2() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = row.createCell(0);
assertDouble(fe, cell, "RATE(3,-10,900)", -0.7563, 0.0001);
}
}
/**
* LibreOffice and Excel return #!NUM, but POI and NumPy return a result
*/
// https://wiki.documentfoundation.org/Documentation/Calc_Functions/RATE
@Disabled("test fails - see related issue")
@Test
void testLibreOfficeInfeasibleSolution() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = row.createCell(0);
assertDouble(fe, cell, "RATE(3,10,900,1,0,0.5)", -0.7634, 0.0001);
}
}
/**
* See https://github.com/numpy/numpy-financial/blob/d02edfb65dcdf23bd571c2cded7fcd4a0528c6af/numpy_financial/tests/test_financial.py#L126
*/
@Test
void testNumPyExample1() throws Exception {
double[] expected = {-0.39920185, -0.02305873, -0.41818459, 0.26513414};
double nper = 2;
double pmt = 0;
double[] pv = {-593.06, -4725.38, -662.05, -428.78};
double[] fv = {214.07, 4509.97, 224.11, 686.29};
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
for(int i = 0; i < pv.length; i++){
String fmla = String.format("RATE(%2f, %2f, %2f, %2f, 0, 0.1)", nper, pmt, pv[i], fv[i]);
HSSFCell cell = row.createCell(i);
assertDouble(fe, cell, fmla, expected[i], 1e-8);
}
}
}
@Test
void testNumPyExample2() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = row.createCell(0);
assertDouble(fe, cell, "RATE(10, 0, -3500, 10000.0, 0, 0.1)", 0.1106908537142689284704528100, 1E-6);
}
}
/**
* RATE will return NaN, if the Newton Raphson method cannot find a
* feasible rate within the required tolerance or number of iterations.
* This can occur if both `pmt` and `pv` have the same sign, as it is
* impossible to repay a loan by making further withdrawls.
*
* See https://github.com/numpy/numpy-financial/blob/d02edfb65dcdf23bd571c2cded7fcd4a0528c6af/numpy_financial/tests/test_financial.py#L113
*/
@Test
void testNumPyInfeasibleSolution1() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = row.createCell(0);
assertError(fe, cell, "RATE(12, 400, 10000, 5000.0, 0, 0.1)", FormulaError.NUM);
}
}
// https://github.com/numpy/numpy-financial/blob/d02edfb65dcdf23bd571c2cded7fcd4a0528c6af/numpy_financial/tests/test_financial.py#L126
@Test
void testNumPyInfeasibleSolution2() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {
HSSFSheet sheet = wb.createSheet();
HSSFRow row = sheet.createRow(0);
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = row.createCell(0);
assertError(fe, cell, "RATE(2, 0, -13.65, -329.67, 0, 0.1)", FormulaError.NUM);
}
}
@Test
void testBug65988() throws Exception {
try (HSSFWorkbook wb = new HSSFWorkbook()) {