Browse Source

Add support for DAverage and DProduct function

pull/1504/head
Antony Liu 5 months ago
parent
commit
278748f49f
  1. 4
      main/SS/Formula/Eval/FunctionEval.cs
  2. 63
      main/SS/Formula/Functions/DAverage.cs
  3. 65
      main/SS/Formula/Functions/DProduct.cs
  4. 9
      main/SS/Formula/Functions/DStarRunner.cs
  5. 76
      testcases/main/SS/Formula/Functions/TestDAverage.cs
  6. 91
      testcases/main/SS/Formula/Functions/TestDProduct.cs

4
main/SS/Formula/Eval/FunctionEval.cs

@ -139,7 +139,7 @@ namespace NPOI.SS.Formula.Eval
retval[39] = NumericFunction.MOD; // MOD
retval[40] = new DStarRunner(DStarRunner.DStarAlgorithmEnum.DCOUNT); // DCOUNT
retval[41] = new DStarRunner(DStarRunner.DStarAlgorithmEnum.DSUM); // DSUM
retval[42] = new NotImplementedFunction("DAVERAGE"); // DAVERAGE
retval[42] = new DStarRunner(DStarRunner.DStarAlgorithmEnum.DAVERAGE); // DAVERAGE
retval[43] = new DStarRunner(DStarRunner.DStarAlgorithmEnum.DMIN); // DMIN
retval[44] = new DStarRunner(DStarRunner.DStarAlgorithmEnum.DMAX);// DMAX
retval[45] = new NotImplementedFunction("DSTDEV"); // DSTDEV
@ -281,7 +281,7 @@ namespace NPOI.SS.Formula.Eval
retval[186] = new NotImplementedFunction("GetWORKSPACE"); // GetWORKSPACE
retval[187] = new NotImplementedFunction("GetWINDOW"); // GetWINDOW
retval[188] = new NotImplementedFunction("GetDOCUMENT"); // GetDOCUMENT
retval[189] = new NotImplementedFunction("DPRODUCT"); // DPRODUCT
retval[189] = new DStarRunner(DStarRunner.DStarAlgorithmEnum.DPRODUCT);
retval[190] = LogicalFunction.ISNONTEXT; // IsNONTEXT
retval[191] = new NotImplementedFunction("GetNOTE"); // GetNOTE
retval[192] = new NotImplementedFunction("NOTE"); // NOTE

63
main/SS/Formula/Functions/DAverage.cs

@ -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.
==================================================================== */
namespace NPOI.SS.Formula.Functions
{
using ExtendedNumerics;
using NPOI.SS.Formula.Eval;
using System.Numerics;
/// <summary>
/// Implementation of the DAverage function:
/// Gets the average value of a column in an area with given conditions.
/// </summary>
public sealed class DAverage : IDStarAlgorithm
{
private long count;
private double total;
public bool ProcessMatch(ValueEval eval)
{
if(eval is NumericValueEval)
{
count++;
total += ((NumericValueEval) eval).NumberValue;
}
return true;
}
public ValueEval Result
{
get
{
return count == 0 ? NumberEval.ZERO : new NumberEval(GetAverage());
}
}
private double GetAverage()
{
return Divide(total, count);
}
private static double Divide(double total, long count)
{
return (double) BigDecimal.Divide(new BigDecimal(total), new BigInteger(count));
}
public bool AllowEmptyMatchField { get; } = false;
}
}

65
main/SS/Formula/Functions/DProduct.cs

@ -0,0 +1,65 @@
/* ====================================================================
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.
==================================================================== */
using System;
using System.Collections;
using System.Collections.Generic;
using System.IO;
using System.Text;
namespace NPOI.SS.Formula.Functions
{
using NPOI.SS.Formula.Eval;
/// <summary>
/// Implementation of the DProduct function:
/// Gets the product value of a column in an area with given conditions.
/// </summary>
public sealed class DProduct : IDStarAlgorithm
{
private double product;
private bool initDone = false;
public bool ProcessMatch(ValueEval eval)
{
if(eval is NumericValueEval)
{
if(initDone)
{
product *= ((NumericValueEval) eval).NumberValue;
}
else
{
product = ((NumericValueEval) eval).NumberValue;
initDone = true;
}
}
return true;
}
public ValueEval Result
{
get
{
return new NumberEval(product);
}
}
public bool AllowEmptyMatchField { get; } = false;
}
}

9
main/SS/Formula/Functions/DStarRunner.cs

@ -40,6 +40,9 @@ namespace NPOI.SS.Formula.Functions
DSUM,
DCOUNT,
DCOUNTA,
DAVERAGE,
DPRODUCT,
}
private DStarAlgorithmEnum algoType;
@ -94,6 +97,12 @@ namespace NPOI.SS.Formula.Functions
case DStarAlgorithmEnum.DCOUNTA:
algorithm = new DCountA();
break;
case DStarAlgorithmEnum.DAVERAGE:
algorithm = new DAverage();
break;
case DStarAlgorithmEnum.DPRODUCT:
algorithm = new DProduct();
break;
default:
throw new InvalidOperationException("Unexpected algorithm type " + algoType + " encountered.");
}

76
testcases/main/SS/Formula/Functions/TestDAverage.cs

@ -0,0 +1,76 @@

/* ====================================================================
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.
==================================================================== */
using System;
using System.Collections;
using System.Collections.Generic;
using System.IO;
using System.Text;
namespace TestCases.SS.Formula.Functions
{
using NPOI.HSSF.UserModel;
using NUnit.Framework;
using TestCases.SS.Util;
/// <summary>
/// Testcase for function DAVERAGE()
/// </summary>
[TestFixture]
public class TestDAverage
{
//https://support.microsoft.com/en-us/office/daverage-function-a6a2d5ac-4b4b-48cd-a1d8-7b37834e5aee
[Test]
public void TestMicrosoftExample1()
{
using(HSSFWorkbook wb = initWorkbook1())
{
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = wb.GetSheetAt(0).GetRow(0).CreateCell(12) as HSSFCell;
Utils.AssertDouble(fe, cell, "DAVERAGE(A4:E10, \"Yield\", A1:B2)", 12);
Utils.AssertDouble(fe, cell, "DAVERAGE(A4:E10, 3, A4:E10)", 13);
Utils.AssertDouble(fe, cell, "DAVERAGE(A4:E10, \"Profit\", A12:A13)", 92.6);
Utils.AssertDouble(fe, cell, "DAVERAGE(A4:E10, \"Profit\", B12:C13)", 82.5);
}
}
private HSSFWorkbook initWorkbook1()
{
HSSFWorkbook wb = new HSSFWorkbook();
HSSFSheet sheet = wb.CreateSheet() as HSSFSheet;
Utils.AddRow(sheet, 0, "Tree", "Height", "Age", "Yield", "Profit", "Height");
Utils.AddRow(sheet, 1, "=Apple", ">10", null, null, null, "<16");
Utils.AddRow(sheet, 2, "=Pear");
Utils.AddRow(sheet, 3, "Tree", "Height", "Age", "Yield", "Profit");
Utils.AddRow(sheet, 4, "Apple", 18, 20, 14, 105);
Utils.AddRow(sheet, 5, "Pear", 12, 12, 10, 96);
Utils.AddRow(sheet, 6, "Cherry", 13, 14, 9, 105);
Utils.AddRow(sheet, 7, "Apple", 14, 15, 10, 75);
Utils.AddRow(sheet, 8, "Pear", 9, 8, 8, 76.8);
Utils.AddRow(sheet, 9, "Apple", 8, 9, 6, 45);
Utils.AddRow(sheet, 10);
Utils.AddRow(sheet, 11, "Tree", "Height", "Height");
Utils.AddRow(sheet, 12, "<>Apple", "<>12", "<>9");
return wb;
}
}
}

91
testcases/main/SS/Formula/Functions/TestDProduct.cs

@ -0,0 +1,91 @@

/* ====================================================================
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 NPOI.HSSF.UserModel;
using NUnit.Framework;
using TestCases.SS.Util;
/// <summary>
/// Testcase for function DPRODUCT()
/// </summary>
[TestFixture]
public class TestDProduct
{
//https://support.microsoft.com/en-us/office/dproduct-function-4f96b13e-d49c-47a7-b769-22f6d017cb31
[Test]
public void TestMicrosoftExample1()
{
using(HSSFWorkbook wb = initWorkbook1(false))
{
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = wb.GetSheetAt(0).GetRow(0).CreateCell(12) as HSSFCell;
Utils.AssertDouble(fe, cell, "DPRODUCT(A5:E11, \"Yield\", A1:F3)", 800, 0.0000000001);
Utils.AssertDouble(fe, cell, "DPRODUCT(A5:E11, \"Yield\", A13:A14)", 720, 0.0000000001);
Utils.AssertDouble(fe, cell, "DPRODUCT(A5:E11, \"Yield\", B13:C14)", 7560, 0.0000000001);
}
}
[Test]
public void TestNoMatch()
{
using(HSSFWorkbook wb = initWorkbook1(true))
{
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
HSSFCell cell = wb.GetSheetAt(0).GetRow(0).CreateCell(12) as HSSFCell;
Utils.AssertDouble(fe, cell, "DPRODUCT(A5:E11, \"Yield\", A1:A2)", 0);
Utils.AssertDouble(fe, cell, "DPRODUCT(A5:E11, \"Yield\", A1:A3)", 604800);
}
}
private HSSFWorkbook initWorkbook1(bool noMatch)
{
HSSFWorkbook wb = new HSSFWorkbook();
HSSFSheet sheet = wb.CreateSheet() as HSSFSheet;
Utils.AddRow(sheet, 0, "Tree", "Height", "Age", "Yield", "Profit", "Height");
if(noMatch)
{
Utils.AddRow(sheet, 1, "=NoMatch");
Utils.AddRow(sheet, 2);
}
else
{
Utils.AddRow(sheet, 1, "=Apple", ">10", null, null, null, "<16");
Utils.AddRow(sheet, 2, "=Pear");
}
Utils.AddRow(sheet, 3);
Utils.AddRow(sheet, 4, "Tree", "Height", "Age", "Yield", "Profit");
Utils.AddRow(sheet, 5, "Apple", 18, 20, 14, 105);
Utils.AddRow(sheet, 6, "Pear", 12, 12, 10, 96);
Utils.AddRow(sheet, 7, "Cherry", 13, 14, 9, 105);
Utils.AddRow(sheet, 8, "Apple", 14, 15, 10, 75);
Utils.AddRow(sheet, 9, "Pear", 9, 8, 8, 77);
Utils.AddRow(sheet, 10, "Apple", 8, 9, 6, 45);
Utils.AddRow(sheet, 11);
Utils.AddRow(sheet, 12, "Tree", "Height", "Height");
Utils.AddRow(sheet, 13, "<>Apple", "<>12", "<>9");
return wb;
}
}
}
Loading…
Cancel
Save