mirror of https://github.com/apache/poi.git
[bug-60924] add support for Excel IFS and SWITCH functions. Thanks to Pieter Degraeuwe
git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@1891856 13f79535-47bb-0310-9956-ffa450edef68
This commit is contained in:
parent
c93d9508ad
commit
cec2d2b4cc
|
@ -136,6 +136,7 @@ public final class AnalysisToolPak implements UDFFinder {
|
|||
r(m, "HEX2DEC", Hex2Dec.instance);
|
||||
r(m, "HEX2OCT", null);
|
||||
r(m, "IFERROR", IfError.instance);
|
||||
r(m, "IFS", Ifs.instance);
|
||||
r(m, "IMABS", null);
|
||||
r(m, "IMAGINARY", Imaginary.instance);
|
||||
r(m, "IMARGUMENT", null);
|
||||
|
@ -181,6 +182,7 @@ public final class AnalysisToolPak implements UDFFinder {
|
|||
r(m, "SINGLE", Single.instance);
|
||||
r(m, "SQRTPI", null);
|
||||
r(m, "SUMIFS", Sumifs.instance);
|
||||
r(m, "SWITCH", Switch.instance);
|
||||
r(m, "TBILLEQ", null);
|
||||
r(m, "TBILLPRICE", null);
|
||||
r(m, "TBILLYIELD", null);
|
||||
|
|
|
@ -0,0 +1,60 @@
|
|||
/* ====================================================================
|
||||
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.BoolEval;
|
||||
import org.apache.poi.ss.formula.eval.ErrorEval;
|
||||
import org.apache.poi.ss.formula.eval.ValueEval;
|
||||
import org.apache.poi.ss.formula.functions.FreeRefFunction;
|
||||
|
||||
/**
|
||||
* Implementation of 'Analysis Toolpak' Excel function IFS()<br>
|
||||
* <p>
|
||||
* The IFS function checks whether one or more conditions are met and returns a value that corresponds to the first TRUE condition.
|
||||
* IFS can take the place of multiple nested IF statements, and is much easier to read with multiple conditions.
|
||||
* <p>
|
||||
* <b>Syntax</b><br>
|
||||
* <b>IFS</b>(IFS([Something is True1, Value if True1, [Something is True2, Value if True2],…[Something is True127, Value if True127]))
|
||||
*
|
||||
* @author Pieter Degraeuwe
|
||||
*/
|
||||
final class Ifs implements FreeRefFunction {
|
||||
|
||||
public static final FreeRefFunction instance = new Ifs();
|
||||
|
||||
private Ifs() {
|
||||
// enforce singleton
|
||||
}
|
||||
|
||||
public ValueEval evaluate(ValueEval[] args, OperationEvaluationContext ec) {
|
||||
if (args.length % 2 != 0) {
|
||||
return ErrorEval.VALUE_INVALID;
|
||||
}
|
||||
|
||||
for (int i = 0; i < args.length; i = i + 2) {
|
||||
BoolEval logicalTest = (BoolEval) args[i];
|
||||
if (logicalTest.getBooleanValue()) {
|
||||
return args[i + 1];
|
||||
}
|
||||
}
|
||||
|
||||
return ErrorEval.NA;
|
||||
}
|
||||
|
||||
}
|
|
@ -0,0 +1,104 @@
|
|||
/* ====================================================================
|
||||
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.BoolEval;
|
||||
import org.apache.poi.ss.formula.eval.ErrorEval;
|
||||
import org.apache.poi.ss.formula.eval.EvaluationException;
|
||||
import org.apache.poi.ss.formula.eval.OperandResolver;
|
||||
import org.apache.poi.ss.formula.eval.ValueEval;
|
||||
import org.apache.poi.ss.formula.functions.FreeRefFunction;
|
||||
|
||||
import static org.apache.poi.ss.formula.eval.RelationalOperationEval.EqualEval;
|
||||
|
||||
/**
|
||||
* Implementation of 'Analysis Toolpak' Excel function SWITCH()<br>
|
||||
* <p>
|
||||
* The SWITCH function evaluates one value (called the expression) against a list of values, and returns the result corresponding to the first matching value.
|
||||
* If there is no match, an optional default value may be returned.
|
||||
* <p>
|
||||
* <b>Syntax</b><br>
|
||||
* <b>SWITCH</b>SWITCH(expression, value1, result1, [default or value2, result2],…[default or value3, result3])
|
||||
*
|
||||
* @author Pieter Degraeuwe
|
||||
*/
|
||||
public final class Switch implements FreeRefFunction {
|
||||
|
||||
public static final FreeRefFunction instance = new Switch();
|
||||
|
||||
private Switch() {
|
||||
// enforce singleton
|
||||
}
|
||||
|
||||
public ValueEval evaluate(ValueEval[] args, OperationEvaluationContext ec) {
|
||||
if (args.length < 3) return ErrorEval.NA;
|
||||
|
||||
final ValueEval expression;
|
||||
try {
|
||||
expression = OperandResolver.getSingleValue(args[0], ec.getRowIndex(), ec.getColumnIndex());
|
||||
} catch (Exception e) {
|
||||
return ErrorEval.NA;
|
||||
}
|
||||
|
||||
for (int i = 1; i < args.length; i = i+2) {
|
||||
|
||||
try {
|
||||
ValueEval value = OperandResolver.getSingleValue(args[i], ec.getRowIndex(), ec.getColumnIndex());
|
||||
ValueEval result = args[i+1];
|
||||
//ValueEval result = OperandResolver.getSingleValue(args[i+1],ec.getRowIndex(),ec.getColumnIndex()) ;
|
||||
|
||||
|
||||
final ValueEval evaluate = EqualEval.evaluate(new ValueEval[]{expression, value}, ec.getRowIndex(), ec.getColumnIndex());
|
||||
if (evaluate instanceof BoolEval) {
|
||||
BoolEval boolEval = (BoolEval) evaluate;
|
||||
final boolean booleanValue = boolEval.getBooleanValue();
|
||||
if (booleanValue) {
|
||||
return result;
|
||||
}
|
||||
|
||||
}
|
||||
|
||||
} catch (EvaluationException e) {
|
||||
return ErrorEval.NA;
|
||||
}
|
||||
|
||||
if (i + 2 == args.length-1) {
|
||||
//last value in args is the default one
|
||||
return args[args.length-1];
|
||||
}
|
||||
|
||||
}
|
||||
|
||||
/*
|
||||
if (args.length % 2 != 0) {
|
||||
return ErrorEval.VALUE_INVALID;
|
||||
}
|
||||
|
||||
for (int i = 0; i < args.length; i = i + 2) {
|
||||
BoolEval logicalTest = (BoolEval) args[i];
|
||||
if (logicalTest.getBooleanValue()) {
|
||||
return args[i + 1];
|
||||
}
|
||||
}
|
||||
*/
|
||||
|
||||
return ErrorEval.NA;
|
||||
}
|
||||
|
||||
}
|
|
@ -0,0 +1,117 @@
|
|||
/* ====================================================================
|
||||
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.hssf.usermodel.HSSFWorkbook;
|
||||
import org.apache.poi.ss.usermodel.Cell;
|
||||
import org.apache.poi.ss.usermodel.CellType;
|
||||
import org.apache.poi.ss.usermodel.FormulaEvaluator;
|
||||
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.util.CellReference;
|
||||
import org.junit.jupiter.api.Test;
|
||||
|
||||
import static org.junit.jupiter.api.Assertions.assertEquals;
|
||||
|
||||
/**
|
||||
* Testcase for 'Analysis Toolpak' function IFS()
|
||||
*
|
||||
* @author Pieter Degraeuwe
|
||||
*/
|
||||
public class TestIfs {
|
||||
|
||||
/**
|
||||
* =IFS(A1="A", "Value for A" , A1="B", "Value for B")
|
||||
*/
|
||||
@Test
|
||||
public void testEvaluate() {
|
||||
Workbook wb = new HSSFWorkbook();
|
||||
Sheet sh = wb.createSheet();
|
||||
Row row1 = sh.createRow(0);
|
||||
|
||||
// Create cells
|
||||
row1.createCell(0, CellType.STRING);
|
||||
|
||||
// Create references
|
||||
CellReference a1Ref = new CellReference("A1");
|
||||
|
||||
// Set values
|
||||
final Cell cellA1 = sh.getRow(a1Ref.getRow()).getCell(a1Ref.getCol());
|
||||
|
||||
|
||||
Cell cell1 = row1.createCell(1);
|
||||
cell1.setCellFormula("IFS(A1=\"A\", \"Value for A\", A1=\"B\",\"Value for B\")");
|
||||
|
||||
FormulaEvaluator evaluator = wb.getCreationHelper().createFormulaEvaluator();
|
||||
|
||||
cellA1.setCellValue("A");
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals("Value for A", evaluator.evaluate(cell1).getStringValue(),
|
||||
"IFS should return 'Value for B'");
|
||||
|
||||
cellA1.setCellValue("B");
|
||||
evaluator.clearAllCachedResultValues();
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals("Value for B", evaluator.evaluate(cell1).getStringValue(),
|
||||
"IFS should return 'Value for B'");
|
||||
}
|
||||
|
||||
/**
|
||||
* where D1 contains a string "A"
|
||||
* =IFS(A1=D1, "Value for A" , A1="B", "Value for B")
|
||||
*/
|
||||
@Test
|
||||
public void testEvaluateForReferenced() {
|
||||
Workbook wb = new HSSFWorkbook();
|
||||
Sheet sh = wb.createSheet();
|
||||
Row row1 = sh.createRow(0);
|
||||
|
||||
// Create cells
|
||||
// row1.createCell(0, CellType.STRING);
|
||||
|
||||
// Create references
|
||||
CellReference a1Ref = new CellReference("A1");
|
||||
CellReference d1Ref = new CellReference("D1");
|
||||
|
||||
// Set values
|
||||
final Cell cellA1 = sh.getRow(a1Ref.getRow()).createCell(a1Ref.getCol());
|
||||
cellA1.setCellFormula("D1");
|
||||
|
||||
final Cell cellD1 = sh.getRow(d1Ref.getRow()).createCell(d1Ref.getCol());
|
||||
cellD1.setCellValue("A");
|
||||
|
||||
|
||||
Cell cell1 = row1.createCell(1);
|
||||
cell1.setCellFormula("IFS(A1=\"A\", \"Value for A\", A1=\"B\",\"Value for B\")");
|
||||
|
||||
FormulaEvaluator evaluator = wb.getCreationHelper().createFormulaEvaluator();
|
||||
|
||||
cellD1.setCellValue("A");
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals( "Value for A", evaluator.evaluate(cell1).getStringValue(),
|
||||
"IFS should return 'Value for B'");
|
||||
|
||||
cellD1.setCellValue("B");
|
||||
evaluator.clearAllCachedResultValues();
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals("Value for B", evaluator.evaluate(cell1).getStringValue(),
|
||||
"IFS should return 'Value for B'");
|
||||
|
||||
}
|
||||
|
||||
}
|
|
@ -0,0 +1,83 @@
|
|||
/* ====================================================================
|
||||
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.hssf.usermodel.HSSFWorkbook;
|
||||
import org.apache.poi.ss.usermodel.Cell;
|
||||
import org.apache.poi.ss.usermodel.CellType;
|
||||
import org.apache.poi.ss.usermodel.FormulaEvaluator;
|
||||
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.util.CellReference;
|
||||
import org.junit.jupiter.api.Test;
|
||||
|
||||
import static org.junit.jupiter.api.Assertions.assertEquals;
|
||||
|
||||
/**
|
||||
* Testcase for 'Analysis Toolpak' function SWITCH()
|
||||
*
|
||||
* @author Pieter Degraeuwe
|
||||
*/
|
||||
public class TestSwitch {
|
||||
|
||||
/**
|
||||
* =SWITCH(A1, "A", "Value for A", "B", "Value for B" )
|
||||
* =SWITCH(A1, "A", "Value for A", "B", "Value for B", "Something else" )
|
||||
*/
|
||||
@Test
|
||||
public void testEvaluate() {
|
||||
Workbook wb = new HSSFWorkbook();
|
||||
Sheet sh = wb.createSheet();
|
||||
Row row1 = sh.createRow(0);
|
||||
|
||||
FormulaEvaluator evaluator = wb.getCreationHelper().createFormulaEvaluator();
|
||||
|
||||
// Create cells
|
||||
row1.createCell(0, CellType.STRING);
|
||||
|
||||
// Create references
|
||||
CellReference a1Ref = new CellReference("A1");
|
||||
|
||||
// Set values
|
||||
final Cell cellA1 = sh.getRow(a1Ref.getRow()).getCell(a1Ref.getCol());
|
||||
|
||||
|
||||
Cell cell1 = row1.createCell(1);
|
||||
cell1.setCellFormula("SWITCH(A1, \"A\",\"Value for A\", \"B\",\"Value for B\", \"Something else\")");
|
||||
|
||||
|
||||
cellA1.setCellValue("A");
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals("Value for A", evaluator.evaluate(cell1).getStringValue(),
|
||||
"SWITCH should return 'Value for A'");
|
||||
|
||||
cellA1.setCellValue("B");
|
||||
evaluator.clearAllCachedResultValues();
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals("Value for B", evaluator.evaluate(cell1).getStringValue(),
|
||||
"SWITCH should return 'Value for B'");
|
||||
|
||||
cellA1.setCellValue("");
|
||||
evaluator.clearAllCachedResultValues();
|
||||
assertEquals(CellType.STRING, evaluator.evaluate(cell1).getCellType());
|
||||
assertEquals("Something else", evaluator.evaluate(cell1).getStringValue(),
|
||||
"SWITCH should return 'Something else'");
|
||||
|
||||
}
|
||||
|
||||
}
|
|
@ -17,15 +17,12 @@
|
|||
==================================================================== */
|
||||
package org.apache.poi.ss.formula.atp;
|
||||
|
||||
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.*;
|
||||
import org.junit.jupiter.api.BeforeEach;
|
||||
import org.junit.jupiter.api.Test;
|
||||
|
||||
import java.util.Arrays;
|
||||
|
||||
import static org.junit.jupiter.api.Assertions.assertEquals;
|
||||
|
||||
/**
|
||||
|
|
Loading…
Reference in New Issue