mirror of https://github.com/apache/poi.git
add FORECAST and FORECAST.LINEAR functions
git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@1901689 13f79535-47bb-0310-9956-ffa450edef68
This commit is contained in:
parent
1bae0a43bf
commit
5574c7b4fd
|
@ -118,6 +118,7 @@ public final class AnalysisToolPak implements UDFFinder {
|
|||
r(m, "FACTDOUBLE", FactDouble.instance);
|
||||
r(m, "FLOOR.MATH", FloorMath.instance);
|
||||
r(m, "FLOOR.PRECISE", FloorPrecise.instance);
|
||||
r(m, "FORECAST.LINEAR", Forecast.instance);
|
||||
r(m, "FVSCHEDULE", null);
|
||||
r(m, "GCD", Gcd.instance);
|
||||
r(m, "GESTEP", null);
|
||||
|
|
|
@ -289,7 +289,7 @@ public final class FunctionEval {
|
|||
// 306: CHITEST
|
||||
retval[307] = Correl.instance;
|
||||
retval[308] = Covar.instanceP;
|
||||
// 309: FORECAST
|
||||
retval[309] = Forecast.instance;
|
||||
// 310: FTEST
|
||||
retval[311] = new Intercept();
|
||||
retval[312] = Correl.instance;
|
||||
|
|
|
@ -30,9 +30,9 @@ import org.apache.poi.ss.formula.eval.ValueEval;
|
|||
import java.util.Arrays;
|
||||
import java.util.List;
|
||||
|
||||
abstract class TwoArrayFunction extends Fixed2ArgFunction {
|
||||
final class ArrayFunctionUtils {
|
||||
|
||||
protected List<DoubleList> getNumberArrays(ValueEval operand0, ValueEval operand1) throws EvaluationException {
|
||||
static List<DoubleList> getNumberArrays(ValueEval operand0, ValueEval operand1) throws EvaluationException {
|
||||
double[] retval0 = collectValuesWithBlanks(operand0).toArray();
|
||||
double[] retval1 = collectValuesWithBlanks(operand1).toArray();
|
||||
if (retval0.length != retval1.length) {
|
||||
|
@ -52,7 +52,7 @@ abstract class TwoArrayFunction extends Fixed2ArgFunction {
|
|||
return Arrays.asList(filtered0, filtered1);
|
||||
}
|
||||
|
||||
private DoubleList collectValuesWithBlanks(ValueEval operand) throws EvaluationException {
|
||||
private static DoubleList collectValuesWithBlanks(ValueEval operand) throws EvaluationException {
|
||||
DoubleList doubleList = new DoubleList();
|
||||
if (operand instanceof ThreeDEval) {
|
||||
ThreeDEval ae = (ThreeDEval) operand;
|
||||
|
@ -111,7 +111,7 @@ abstract class TwoArrayFunction extends Fixed2ArgFunction {
|
|||
return doubleList;
|
||||
}
|
||||
|
||||
private Double collectValue(ValueEval ve) throws EvaluationException {
|
||||
private static Double collectValue(ValueEval ve) throws EvaluationException {
|
||||
if (ve == null) {
|
||||
throw new IllegalArgumentException("ve must not be null");
|
||||
}
|
|
@ -24,6 +24,8 @@ import org.apache.poi.ss.formula.eval.ValueEval;
|
|||
|
||||
import java.util.List;
|
||||
|
||||
import static org.apache.poi.ss.formula.functions.ArrayFunctionUtils.getNumberArrays;
|
||||
|
||||
/**
|
||||
* Implementation for Excel CORREL() function.
|
||||
* <p>
|
||||
|
@ -38,7 +40,7 @@ import java.util.List;
|
|||
* See https://support.microsoft.com/en-us/office/correl-function-995dcef7-0c0a-4bed-a3fb-239d7b68ca92
|
||||
* </p>
|
||||
*/
|
||||
public class Correl extends TwoArrayFunction {
|
||||
public class Correl extends Fixed2ArgFunction {
|
||||
|
||||
public static final Correl instance = new Correl();
|
||||
|
||||
|
|
|
@ -26,6 +26,8 @@ import org.apache.poi.ss.formula.eval.ValueEval;
|
|||
|
||||
import java.util.List;
|
||||
|
||||
import static org.apache.poi.ss.formula.functions.ArrayFunctionUtils.getNumberArrays;
|
||||
|
||||
/**
|
||||
* Implementation for Excel COVAR() and COVARIANCE.P() functions.
|
||||
* <p>
|
||||
|
@ -35,7 +37,7 @@ import java.util.List;
|
|||
* @see <a href="https://support.microsoft.com/en-us/office/covariance-p-function-6f0e1e6d-956d-4e4b-9943-cfef0bf9edfc">COVARIANCE.P</a>
|
||||
* </p>
|
||||
*/
|
||||
public class Covar extends TwoArrayFunction implements FreeRefFunction {
|
||||
public class Covar extends Fixed2ArgFunction implements FreeRefFunction {
|
||||
|
||||
public static final Covar instanceP = new Covar(false);
|
||||
public static final Covar instanceS = new Covar(true);
|
||||
|
|
|
@ -0,0 +1,93 @@
|
|||
/* ====================================================================
|
||||
Licensed to the Apache Software Foundation (ASF) under one or more
|
||||
contributor license agreements. See the NOTICE file distributed with
|
||||
this work for additional information regarding copyright ownership.
|
||||
The ASF licenses this file to You under the Apache License, Version 2.0
|
||||
(the "License"); you may not use this file except in compliance with
|
||||
the License. You may obtain a copy of the License at
|
||||
|
||||
http://www.apache.org/licenses/LICENSE-2.0
|
||||
|
||||
Unless required by applicable law or agreed to in writing, software
|
||||
distributed under the License is distributed on an "AS IS" BASIS,
|
||||
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||
See the License for the specific language governing permissions and
|
||||
limitations under the License.
|
||||
==================================================================== */
|
||||
package org.apache.poi.ss.formula.functions;
|
||||
|
||||
import org.apache.poi.ss.formula.OperationEvaluationContext;
|
||||
import org.apache.poi.ss.formula.eval.ErrorEval;
|
||||
import org.apache.poi.ss.formula.eval.EvaluationException;
|
||||
import org.apache.poi.ss.formula.eval.NumberEval;
|
||||
import org.apache.poi.ss.formula.eval.OperandResolver;
|
||||
import org.apache.poi.ss.formula.eval.ValueEval;
|
||||
|
||||
import java.util.List;
|
||||
|
||||
import static org.apache.poi.ss.formula.functions.ArrayFunctionUtils.getNumberArrays;
|
||||
|
||||
/**
|
||||
* Implementation for Excel FORECAST() and FORECAST.LINEAR() functions.
|
||||
* <p>
|
||||
* <b>Syntax</b>:<br> <b>FORECAST </b>(<b>number</b>, <b>array1</b>, <b>array2</b>)<br>
|
||||
* </p>
|
||||
* <p>
|
||||
* See https://support.microsoft.com/en-us/office/forecast-and-forecast-linear-functions-50ca49c9-7b40-4892-94e4-7ad38bbeda99
|
||||
* </p>
|
||||
*/
|
||||
public class Forecast extends Fixed3ArgFunction implements FreeRefFunction {
|
||||
|
||||
public static final Forecast instance = new Forecast();
|
||||
|
||||
private Forecast() {}
|
||||
|
||||
@Override
|
||||
public ValueEval evaluate(int srcRowIndex, int srcColumnIndex, ValueEval arg0, ValueEval arg1, ValueEval arg2) {
|
||||
try {
|
||||
final Double x = evaluateValue(arg0, srcRowIndex, srcColumnIndex);
|
||||
if (x == null || x.isNaN() || x.isInfinite()) {
|
||||
return ErrorEval.VALUE_INVALID;
|
||||
}
|
||||
final List<DoubleList> arrays = getNumberArrays(arg1, arg2);
|
||||
final double[] arrY = arrays.get(0).toArray();
|
||||
final double[] arrX = arrays.get(1).toArray();
|
||||
final double averageY = MathX.average(arrY);
|
||||
final double averageX = MathX.average(arrX);
|
||||
double bnum = 0;
|
||||
double bdem = 0;
|
||||
final int len = arrY.length;
|
||||
for (int i = 0; i < len; i++) {
|
||||
double diff0 = arrX[i] - averageX;
|
||||
bnum += diff0 * (arrY[i] - averageY);
|
||||
bdem += Math.pow(diff0, 2);
|
||||
}
|
||||
if (bdem == 0) {
|
||||
return ErrorEval.DIV_ZERO;
|
||||
}
|
||||
|
||||
final double b = bnum / bdem;
|
||||
final double a = averageY - (b * averageX);
|
||||
final double res = a + (b * x);
|
||||
return new NumberEval(res);
|
||||
} catch (EvaluationException e) {
|
||||
return e.getErrorEval();
|
||||
} catch (Exception e) {
|
||||
return ErrorEval.NA;
|
||||
}
|
||||
}
|
||||
|
||||
@Override
|
||||
public ValueEval evaluate(ValueEval[] args, OperationEvaluationContext ec) {
|
||||
if (args.length != 3) {
|
||||
return ErrorEval.VALUE_INVALID;
|
||||
}
|
||||
return evaluate(ec.getRowIndex(), ec.getColumnIndex(), args[0], args[1], args[2]);
|
||||
}
|
||||
|
||||
private static Double evaluateValue(ValueEval arg, int srcRowIndex, int srcColumnIndex) throws EvaluationException {
|
||||
ValueEval veText = OperandResolver.getSingleValue(arg, srcRowIndex, srcColumnIndex);
|
||||
String strText1 = OperandResolver.coerceValueToString(veText);
|
||||
return OperandResolver.parseDouble(strText1);
|
||||
}
|
||||
}
|
|
@ -60,6 +60,7 @@ final class TestCorrel {
|
|||
assertDouble(fe, cell, "PEARSON(A2:A6,B2:B6)", 0.699379, 0.0000005);
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testBlankValue() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(null)) {
|
||||
|
|
|
@ -0,0 +1,63 @@
|
|||
/* ====================================================================
|
||||
Licensed to the Apache Software Foundation (ASF) under one or more
|
||||
contributor license agreements. See the NOTICE file distributed with
|
||||
this work for additional information regarding copyright ownership.
|
||||
The ASF licenses this file to You under the Apache License, Version 2.0
|
||||
(the "License"); you may not use this file except in compliance with
|
||||
the License. You may obtain a copy of the License at
|
||||
|
||||
http://www.apache.org/licenses/LICENSE-2.0
|
||||
|
||||
Unless required by applicable law or agreed to in writing, software
|
||||
distributed under the License is distributed on an "AS IS" BASIS,
|
||||
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||
See the License for the specific language governing permissions and
|
||||
limitations under the License.
|
||||
==================================================================== */
|
||||
|
||||
package org.apache.poi.ss.formula.functions;
|
||||
|
||||
import org.apache.poi.hssf.usermodel.HSSFCell;
|
||||
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.Test;
|
||||
|
||||
import java.io.IOException;
|
||||
|
||||
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;
|
||||
|
||||
/**
|
||||
* Tests for {@link Forecast}
|
||||
*/
|
||||
final class TestForecast {
|
||||
|
||||
//https://support.microsoft.com/en-us/office/forecast-and-forecast-linear-functions-50ca49c9-7b40-4892-94e4-7ad38bbeda99
|
||||
@Test
|
||||
void testMicrosoftExample1() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1()) {
|
||||
HSSFSheet sheet = wb.getSheetAt(0);
|
||||
HSSFRow row = sheet.getRow(0);
|
||||
HSSFCell cell = row.createCell(100);
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
assertDouble(fe, cell, "FORECAST(30,A2:A6,B2:B6)", 10.607253, 0.0000001);
|
||||
assertDouble(fe, cell, "FORECAST.LINEAR(30,A2:A6,B2:B6)", 10.607253, 0.0000001);
|
||||
}
|
||||
}
|
||||
|
||||
private HSSFWorkbook initWorkbook1() {
|
||||
HSSFWorkbook wb = new HSSFWorkbook();
|
||||
HSSFSheet sheet = wb.createSheet();
|
||||
addRow(sheet, 0, "Known X", "Known Y");
|
||||
addRow(sheet, 1, 6, 20);
|
||||
addRow(sheet, 2, 7, 28);
|
||||
addRow(sheet, 3, 9, 31);
|
||||
addRow(sheet, 4, 15, 38);
|
||||
addRow(sheet, 5, 21, 40);
|
||||
return wb;
|
||||
}
|
||||
}
|
Loading…
Reference in New Issue