diff --git a/build/_build.csproj.DotSettings b/build/_build.csproj.DotSettings index 7bc28484c..337271da9 100644 --- a/build/_build.csproj.DotSettings +++ b/build/_build.csproj.DotSettings @@ -16,6 +16,8 @@ False <Policy Inspect="True" Prefix="" Suffix="" Style="AaBb" /> <Policy Inspect="True" Prefix="" Suffix="" Style="AaBb" /> + <Policy><Descriptor Staticness="Instance" AccessRightKinds="Private" Description="Instance fields (private)"><ElementKinds><Kind Name="FIELD" /><Kind Name="READONLY_FIELD" /></ElementKinds></Descriptor><Policy Inspect="True" Prefix="" Suffix="" Style="AaBb" /></Policy> + <Policy><Descriptor Staticness="Static" AccessRightKinds="Private" Description="Static fields (private)"><ElementKinds><Kind Name="FIELD" /></ElementKinds></Descriptor><Policy Inspect="True" Prefix="" Suffix="" Style="AaBb" /></Policy> True True True @@ -24,4 +26,5 @@ True True True - True + True + True diff --git a/main/SS/Formula/Eval/FunctionEval.cs b/main/SS/Formula/Eval/FunctionEval.cs index e827bbb12..abcc9607d 100644 --- a/main/SS/Formula/Eval/FunctionEval.cs +++ b/main/SS/Formula/Eval/FunctionEval.cs @@ -391,7 +391,7 @@ private static Function[] ProduceFunctions() retval[306] = new NotImplementedFunction("CHITEST"); // CHITEST retval[307] = new NotImplementedFunction("CORREL"); // CORREL retval[308] = new NotImplementedFunction("COVAR"); // COVAR - retval[309] = new NotImplementedFunction("FORECAST"); // FORECAST + retval[309] = new Forecast(); // FORECAST retval[310] = new NotImplementedFunction("FTEST"); // FTEST retval[311] = new Intercept(); // INTERCEPT retval[312] = new NotImplementedFunction("PEARSON"); // PEARSON diff --git a/main/SS/Formula/Functions/Forecast.cs b/main/SS/Formula/Functions/Forecast.cs new file mode 100644 index 000000000..5b381aa93 --- /dev/null +++ b/main/SS/Formula/Functions/Forecast.cs @@ -0,0 +1,150 @@ +using System; +using NPOI.SS.Formula.Eval; + +namespace NPOI.SS.Formula.Functions +{ + /// + /// The Forecast class is a representation of the Excel FORECAST function. + /// This function predicts a future value along a linear trend line based on existing historical data. + /// The class inherits from the Fixed3ArgFunction class and overrides the Evaluate method. + /// The Evaluate method takes three arguments: the x-value for which we want to forecast a y-value, + /// and two arrays of x-values and y-values representing historical data. + /// The method calculates the slope and intercept of the line of best fit for the historical data + /// and uses these to calculate the forecast y-value. + /// The class also includes methods for converting ValueEval objects to numeric arrays and for creating ValueVectors. + /// + public class Forecast : Fixed3ArgFunction + { + public override ValueEval Evaluate(int srcRowIndex, int srcColumnIndex, ValueEval arg0, ValueEval arg1, + ValueEval arg2) + { + try + { + if(arg0 is ErrorEval arg0Error) + { + return arg0Error; + } + + if(arg1 is ErrorEval arg1Error) + { + return arg1Error; + } + + if(arg2 is ErrorEval arg2Error) + { + return arg2Error; + } + + double x = NumericFunction.SingleOperandEvaluate(arg0, srcRowIndex, srcColumnIndex); + double[] yValues = GetNumericArray(arg1); + double[] xValues = GetNumericArray(arg2); + + if(yValues.Length != xValues.Length) + { + return ErrorEval.NA; + } + + double xSum = 0, ySum = 0, xySum = 0, xSquareSum = 0; + int n = xValues.Length; + + for(int i = 0; i < n; i++) + { + xSum += xValues[i]; + ySum += yValues[i]; + xySum += xValues[i] * yValues[i]; + xSquareSum += Math.Pow(xValues[i], 2); + } + + double slope = (n * xySum - xSum * ySum) / (n * xSquareSum - Math.Pow(xSum, 2)); + double intercept = (ySum - slope * xSum) / n; + + double forecastY = slope * x + intercept; + + return new NumberEval(forecastY); + } + catch(EvaluationException e) + { + return e.GetErrorEval(); + } + } + + private static double[] GetNumericArray(ValueEval arg) + { + ValueVector vv = CreateValueVector(arg); + double[] result = new double[vv.Size]; + for(int i = 0; i < vv.Size; i++) + { + ValueEval v = vv.GetItem(i); + if(v is ErrorEval errorEval) + { + throw new EvaluationException(errorEval); + } + + if(v is NumberEval numberEval) + { + result[i] = numberEval.NumberValue; + } + } + + return result; + } + + private static ValueVector CreateValueVector(ValueEval arg) + { + return arg switch { + ErrorEval eval => throw new EvaluationException(eval), + TwoDEval dEval => new AreaValueArray(dEval), + RefEval refEval => new RefValueArray(refEval), + _ => new SingleCellValueArray(arg) + }; + } + + private abstract class ValueArray(int size) : ValueVector + { + public ValueEval GetItem(int index) + { + if(index < 0 || index > size) + { + throw new ArgumentException($"Specified index {index} is outside range (0..{(size - 1)})"); + } + + return GetItemInternal(index); + } + + protected abstract ValueEval GetItemInternal(int index); + + public int Size => size; + } + + private class SingleCellValueArray(ValueEval value) : ValueArray(1) + { + protected override ValueEval GetItemInternal(int index) + { + return value; + } + } + + private class RefValueArray(RefEval ref1) : ValueArray(ref1.NumberOfSheets) + { + private readonly int _width = ref1.NumberOfSheets; + + protected override ValueEval GetItemInternal(int index) + { + int sIx = (index % _width) + ref1.FirstSheetIndex; + return ref1.GetInnerValueEval(sIx); + } + } + + private class AreaValueArray(TwoDEval ae) : ValueArray(ae.Width * ae.Height) + { + private readonly int _width = ae.Width; + + protected override ValueEval GetItemInternal(int index) + { + int rowIx = index / _width; + int colIx = index % _width; + return ae.GetValue(rowIx, colIx); + } + } + } +} \ No newline at end of file diff --git a/testcases/main/SS/Formula/Functions/TestForecast.cs b/testcases/main/SS/Formula/Functions/TestForecast.cs new file mode 100644 index 000000000..256c0113b --- /dev/null +++ b/testcases/main/SS/Formula/Functions/TestForecast.cs @@ -0,0 +1,193 @@ +/* + * ==================================================================== + * 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. + * ==================================================================== + */ + +namespace TestCases.SS.Formula.Functions +{ + using NUnit.Framework; + using System; + using HSSF; + using NPOI.SS.Formula.Eval; + using NPOI.HSSF.UserModel; + using NPOI.SS.UserModel; + using NPOI.SS.Formula.Functions; + + /** + * Test for Excel function FORECAST() + * + * @author Ken Smith + */ + [TestFixture] + public class TestForecast + { + private static readonly Function FORECAST = new Forecast(); + + /// + /// This test is replicated in the "TestBasic" tab of the "Forecast.xls" file. + /// + [Test] + public void TestBasic() + { + ValueEval x = new NumberEval(100); + ValueEval[] yValues = [ + new NumberEval(1), + new NumberEval(2), + new NumberEval(3), + new NumberEval(4), + new NumberEval(5), + new NumberEval(6) + ]; + + ValueEval[] xValues = [ + new NumberEval(2), + new NumberEval(4), + new NumberEval(6), + new NumberEval(8), + new NumberEval(10), + new NumberEval(12) + ]; + Confirm(x, CreateAreaEval(yValues), CreateAreaEval(xValues), 50.0); + // Excel 365 build 2402 gives 50.0 + } + + /// + /// This test is replicated in the "TestLargeNumbers" tab of the "Forecast.xls" file. + /// + [Test] + public void TestLargeNumbers() + { + double exp = Math.Pow(10, 7.5); + ValueEval x = new NumberEval(100); + ValueEval[] yValues = [ + new NumberEval(3 + exp), + new NumberEval(4 + exp), + new NumberEval(2 + exp), + new NumberEval(5 + exp), + new NumberEval(4 + exp), + new NumberEval(7 + exp) + ]; + + ValueEval[] xValues = [ + new NumberEval(1), + new NumberEval(2), + new NumberEval(3), + new NumberEval(4), + new NumberEval(5), + new NumberEval(6) + ]; + Confirm(x, CreateAreaEval(yValues), CreateAreaEval(xValues), 31622844.1826363); + // Excel 365 build 2402 gives 31622844.1826363 + } + + /// + /// This test is replicated in the "TestLargeArrays" tab of the "Forecast.xls" file. + /// + [Test] + public void TestLargeArrays() + { + ValueEval x = new NumberEval(100); + ValueEval[] yValues = CreateMockNumberArray(100, 3); // [2,2,0,1,2,0,...,0,1] + yValues[0] = new NumberEval(2.0); // Changes first element to 2 + ValueEval[] xValues = CreateMockNumberArray(100, 101); // [1,2,3,4,...,99,100] + + Confirm(x, CreateAreaEval(yValues), CreateAreaEval(xValues), 0.960990099); + // Excel 365 build 2402 gives 0.960990099 + } + + [Test] + public void TestErrors() + { + NumberEval x = new(100); + + ValueEval areaEval1 = CreateAreaEval([new NumberEval(2)]); + ValueEval areaEval2 = CreateAreaEval([new NumberEval(2), new NumberEval(2)]); // different size + + ValueEval areaEvalWithNullError = CreateAreaEval([new NumberEval(2), ErrorEval.NULL_INTERSECTION]); + ValueEval areaEvalWithRefError = CreateAreaEval([ErrorEval.REF_INVALID, new NumberEval(2)]); + + // if either arg is an error, that error propagates + ConfirmError(x, ErrorEval.REF_INVALID, ErrorEval.NAME_INVALID, ErrorEval.REF_INVALID); + ConfirmError(x, areaEvalWithRefError, ErrorEval.NAME_INVALID, ErrorEval.NAME_INVALID); + ConfirmError(x, ErrorEval.NAME_INVALID, areaEvalWithRefError, ErrorEval.NAME_INVALID); + + // array sizes must match + ConfirmError(x, areaEval1, areaEval2, ErrorEval.NA); + + // any error in an array item propagates up + ConfirmError(x, areaEvalWithRefError, areaEvalWithRefError, ErrorEval.REF_INVALID); + + // search for errors array by array, not pair by pair + ConfirmError(x, areaEvalWithRefError, areaEvalWithNullError, ErrorEval.REF_INVALID); + ConfirmError(x, areaEvalWithNullError, areaEvalWithRefError, ErrorEval.NULL_INTERSECTION); + } + + /** + * Example from + * https://support.microsoft.com/en-us/office/forecast-and-forecast-linear-functions-50ca49c9-7b40-4892-94e4-7ad38bbeda99 + */ + [Test] + public void TestFromFile() + { + IWorkbook wb = HSSFTestDataSamples.OpenSampleWorkbook("Forecast.xls"); + HSSFFormulaEvaluator fe = new(wb); + + ISheet example1 = wb.GetSheet("TestFromFile"); + ICell a8 = example1.GetRow(7).GetCell(0); + Assert.AreEqual("FORECAST(30,A2:A6,B2:B6)", a8.CellFormula); + fe.Evaluate(a8); + Assert.AreEqual(10.60725309, a8.NumericCellValue, 0.00000001); + } + + private static ValueEval Invoke(ValueEval x, ValueEval yArray, ValueEval xArray) + { + ValueEval[] args = [x, yArray, xArray]; + return FORECAST.Evaluate(args, -1, (short) -1); + } + + private static void Confirm(ValueEval x, ValueEval yArray, ValueEval xArray, double expected) + { + ValueEval result = Invoke(x, yArray, xArray); + Assert.AreEqual(typeof(NumberEval), result.GetType()); + Assert.AreEqual(expected, ((NumberEval) result).NumberValue, expected * .000000001); + } + + private static void ConfirmError(ValueEval x, ValueEval yArray, ValueEval xArray, ErrorEval expectedError) + { + ValueEval result = Invoke(x, yArray, xArray); + Assert.AreEqual(typeof(ErrorEval), result.GetType()); + Assert.AreEqual(expectedError, (ErrorEval) result); + } + + private static ValueEval[] CreateMockNumberArray(int size, double value) + { + ValueEval[] result = new ValueEval[size]; + for(int i = 0; i < result.Length; i++) + { + result[i] = new NumberEval((i + 1) % value); + } + + return result; + } + + private static ValueEval CreateAreaEval(ValueEval[] values) + { + string refStr = "A1:A" + values.Length; + return EvalFactory.CreateAreaEval(refStr, values); + } + } +} \ No newline at end of file diff --git a/testcases/test-data/spreadsheet/Forecast.xls b/testcases/test-data/spreadsheet/Forecast.xls new file mode 100644 index 000000000..cddc1f6e3 Binary files /dev/null and b/testcases/test-data/spreadsheet/Forecast.xls differ