<changes>
<release version="3.8-beta1" date="2010-??-??">
+ <action dev="POI-DEVELOPERS" type="add">48539 - Added implementation for MROUND(), VAR() and VARP()</action>
<action dev="POI-DEVELOPERS" type="add">50446 - Code cleanup and optimizations to keep some IDE quiet</action>
<action dev="POI-DEVELOPERS" type="add">50437 - Support passing ranges to NPV()</action>
<action dev="POI-DEVELOPERS" type="add">50409 - Added implementation for IRR()</action>
r(m, "JIS", null);
r(m, "LCM", null);
r(m, "MDURATION", null);
- r(m, "MROUND", null);
+ r(m, "MROUND", MRound.instance);
r(m, "MULTINOMIAL", null);
r(m, "NETWORKDAYS", null);
r(m, "NOMINAL", null);
--- /dev/null
+/* ====================================================================
+ 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.atp;
+
+import org.apache.poi.ss.formula.OperationEvaluationContext;
+import org.apache.poi.ss.formula.eval.*;
+import org.apache.poi.ss.formula.functions.FreeRefFunction;
+import org.apache.poi.ss.formula.functions.NumericFunction;
+import org.apache.poi.ss.usermodel.DateUtil;
+
+import java.util.Calendar;
+import java.util.GregorianCalendar;
+import java.util.regex.Pattern;
+
+/**
+ * Implementation of Excel 'Analysis ToolPak' function MROUND()<br/>
+ *
+ * Returns a number rounded to the desired multiple.<p/>
+ *
+ * <b>Syntax</b><br/>
+ * <b>MROUND</b>(<b>number</b>, <b>multiple</b>)
+ *
+ * <p/>
+ *
+ * @author Yegor Kozlov
+ */
+final class MRound implements FreeRefFunction {
+
+ public static final FreeRefFunction instance = new MRound();
+
+ private MRound() {
+ // enforce singleton
+ }
+
+ public ValueEval evaluate(ValueEval[] args, OperationEvaluationContext ec) {
+ double number, multiple, result;
+
+ if (args.length != 2) {
+ return ErrorEval.VALUE_INVALID;
+ }
+
+ try {
+ number = OperandResolver.coerceValueToDouble(OperandResolver.getSingleValue(args[0], ec.getRowIndex(), ec.getColumnIndex()));
+ multiple = OperandResolver.coerceValueToDouble(OperandResolver.getSingleValue(args[1], ec.getRowIndex(), ec.getColumnIndex()));
+
+ if( multiple == 0.0 ) {
+ result = 0.0;
+ } else {
+ if(number*multiple < 0) {
+ // Returns #NUM! because the number and the multiple have different signs
+ throw new EvaluationException(ErrorEval.NUM_ERROR);
+ }
+ result = multiple * Math.round( number / multiple );
+ }
+ NumericFunction.checkValue(result);
+ return new NumberEval(result);
+ } catch (EvaluationException e) {
+ return e.getErrorEval();
+ }
+ }
+}
retval[37] = BooleanFunction.OR;
retval[38] = BooleanFunction.NOT;
retval[39] = NumericFunction.MOD;
+
+ retval[46] = AggregateFunction.VAR;
retval[48] = TextFunction.TEXT;
retval[56] = FinanceFunction.PV;
retval[184] = NumericFunction.FACT;
retval[190] = LogicalFunction.ISNONTEXT;
+ retval[194] = AggregateFunction.VARP;
retval[197] = NumericFunction.TRUNC;
retval[198] = LogicalFunction.ISLOGICAL;
return MathX.sumsq(values);
}
};
+ public static final Function VAR = new AggregateFunction() {
+ protected double evaluate(double[] values) throws EvaluationException {
+ if (values.length < 1) {
+ throw new EvaluationException(ErrorEval.DIV_ZERO);
+ }
+ return StatsLib.var(values);
+ }
+ };
+ public static final Function VARP = new AggregateFunction() {
+ protected double evaluate(double[] values) throws EvaluationException {
+ if (values.length < 1) {
+ throw new EvaluationException(ErrorEval.DIV_ZERO);
+ }
+ return StatsLib.varp(values);
+ }
+ };
}
/**
* @throws EvaluationException (#NUM!) if <tt>result</tt> is <tt>NaN</> or <tt>Infinity</tt>
*/
- static final void checkValue(double result) throws EvaluationException {
+ public static final void checkValue(double result) throws EvaluationException {
if (Double.isNaN(result) || Double.isInfinite(result)) {
throw new EvaluationException(ErrorEval.NUM_ERROR);
}
return r;
}
+ public static double var(double[] v) {
+ double r = Double.NaN;
+ if (v!=null && v.length > 1) {
+ r = devsq(v) / (v.length - 1);
+ }
+ return r;
+ }
+
+ public static double varp(double[] v) {
+ double r = Double.NaN;
+ if (v!=null && v.length > 1) {
+ r = devsq(v) /v.length;
+ }
+ return r;
+ }
public static double median(double[] v) {
double r = Double.NaN;
import org.apache.poi.openxml4j.opc.OPCPackage;
import org.apache.poi.openxml4j.opc.PackagePart;
import org.apache.poi.openxml4j.opc.PackagingURIHelper;
-import org.apache.poi.ss.usermodel.BaseTestBugzillaIssues;
-import org.apache.poi.ss.usermodel.Cell;
-import org.apache.poi.ss.usermodel.DataFormatter;
-import org.apache.poi.ss.usermodel.Font;
-import org.apache.poi.ss.usermodel.FormulaError;
-import org.apache.poi.ss.usermodel.FormulaEvaluator;
-import org.apache.poi.ss.usermodel.Name;
-import org.apache.poi.ss.usermodel.Row;
-import org.apache.poi.ss.usermodel.Sheet;
-import org.apache.poi.ss.usermodel.Workbook;
+import org.apache.poi.ss.usermodel.*;
+import org.apache.poi.ss.formula.eval.NotImplementedException;
import org.apache.poi.xssf.XSSFITestDataProvider;
import org.apache.poi.xssf.XSSFTestDataSamples;
import org.apache.poi.xssf.model.CalculationChain;
* NameXPtgs.
* Blows up on:
* IF(B6= (ROUNDUP(B6,0) + ROUNDDOWN(B6,0))/2, MROUND(B6,2),ROUND(B6,0))
+ *
+ * TODO: delete this test case when MROUND and VAR are implemented
*/
- public void DISABLEDtest48539() throws Exception {
+ public void test48539() throws Exception {
XSSFWorkbook wb = XSSFTestDataSamples.openSampleWorkbook("48539.xlsx");
assertEquals(3, wb.getNumberOfSheets());
for(Row r : s) {
for(Cell c : r) {
if(c.getCellType() == Cell.CELL_TYPE_FORMULA) {
- eval.evaluate(c);
+ CellValue cv = eval.evaluate(c);
+ if(cv.getCellType() == Cell.CELL_TYPE_NUMERIC) {
+ // assert that the calculated value agrees with
+ // the cached formula result calculated by Excel
+ double cachedFormulaResult = c.getNumericCellValue();
+ double evaluatedFormulaResult = cv.getNumberValue();
+ assertEquals(c.getCellFormula(), cachedFormulaResult, evaluatedFormulaResult, 1E-7);
+ }
}
}
}
}
// Now all of them
- XSSFFormulaEvaluator.evaluateAllFormulaCells(wb);
+ XSSFFormulaEvaluator.evaluateAllFormulaCells(wb);
}
/**
--- /dev/null
+/* ====================================================================
+ 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.atp;
+
+import junit.framework.TestCase;
+import org.apache.poi.hssf.HSSFTestDataSamples;
+import org.apache.poi.hssf.usermodel.HSSFWorkbook;
+import org.apache.poi.ss.formula.eval.ErrorEval;
+import org.apache.poi.ss.usermodel.*;
+
+/**
+ * Testcase for 'Analysis Toolpak' function MROUND()
+ *
+ * @author Yegor Kozlov
+ */
+public class TestMRound extends TestCase {
+
+ /**
+=MROUND(10, 3) Rounds 10 to a nearest multiple of 3 (9)
+=MROUND(-10, -3) Rounds -10 to a nearest multiple of -3 (-9)
+=MROUND(1.3, 0.2) Rounds 1.3 to a nearest multiple of 0.2 (1.4)
+=MROUND(5, -2) Returns an error, because -2 and 5 have different signs (#NUM!) *
+ */
+ public static void testEvaluate(){
+ Workbook wb = new HSSFWorkbook();
+ Sheet sh = wb.createSheet();
+ Cell cell1 = sh.createRow(0).createCell(0);
+ cell1.setCellFormula("MROUND(10, 3)");
+ Cell cell2 = sh.createRow(0).createCell(0);
+ cell2.setCellFormula("MROUND(-10, -3)");
+ Cell cell3 = sh.createRow(0).createCell(0);
+ cell3.setCellFormula("MROUND(1.3, 0.2)");
+ Cell cell4 = sh.createRow(0).createCell(0);
+ cell4.setCellFormula("MROUND(5, -2)");
+ Cell cell5 = sh.createRow(0).createCell(0);
+ cell5.setCellFormula("MROUND(5, 0)");
+
+ double accuracy = 1E-9;
+
+ FormulaEvaluator evaluator = wb.getCreationHelper().createFormulaEvaluator();
+
+ assertEquals("Rounds 10 to a nearest multiple of 3 (9)",
+ 9.0, evaluator.evaluate(cell1).getNumberValue(), accuracy);
+
+ assertEquals("Rounds -10 to a nearest multiple of -3 (-9)",
+ -9.0, evaluator.evaluate(cell2).getNumberValue(), accuracy);
+
+ assertEquals("Rounds 1.3 to a nearest multiple of 0.2 (1.4)",
+ 1.4, evaluator.evaluate(cell3).getNumberValue(), accuracy);
+
+ assertEquals("Returns an error, because -2 and 5 have different signs (#NUM!)",
+ ErrorEval.NUM_ERROR.getErrorCode(), evaluator.evaluate(cell4).getErrorValue());
+
+ assertEquals("Returns 0 because the multiple is 0",
+ 0.0, evaluator.evaluate(cell5).getNumberValue());
+ }
+}
x = 3.02765035410;
assertEquals("stdev ", x, d);
}
+
+ public void testVar() {
+ double[] v = null;
+ double d, x = 0;
+
+ v = new double[] {3.50, 5.00, 7.23, 2.99};
+ d = StatsLib.var(v);
+ x = 3.6178;
+ assertEquals("var ", x, d);
+
+ v = new double[] {34.5, 2.0, 8.9, -4.0};
+ d = StatsLib.var(v);
+ x = 286.99;
+ assertEquals("var ", x, d);
+
+ v = new double[] {7.0, 25.0, 21.69};
+ d = StatsLib.var(v);
+ x = 91.79203333;
+ assertEquals("var ", x, d);
+
+ v = new double[] {1345,1301,1368,1322,1310,1370,1318,1350,1303,1299};
+ d = StatsLib.var(v);
+ x = 754.2666667;
+ assertEquals("var ", x, d);
+ }
+
+ public void testVarp() {
+ double[] v = null;
+ double d, x = 0;
+
+ v = new double[] {3.50, 5.00, 7.23, 2.99};
+ d = StatsLib.varp(v);
+ x = 2.71335;
+ assertEquals("varp ", x, d);
+
+ v = new double[] {34.5, 2.0, 8.9, -4.0};
+ d = StatsLib.varp(v);
+ x = 215.2425;
+ assertEquals("varp ", x, d);
+
+ v = new double[] {7.0, 25.0, 21.69};
+ d = StatsLib.varp(v);
+ x = 61.19468889;
+ assertEquals("varp ", x, d);
+
+ v = new double[] {1345,1301,1368,1322,1310,1370,1318,1350,1303,1299};
+ d = StatsLib.varp(v);
+ x = 678.84;
+ assertEquals("varp ", x, d);
+ }
}