mirror of https://github.com/apache/poi.git
[bug-66098] support wildcard matches in D* functions
git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@1901385 13f79535-47bb-0310-9956-ffa450edef68
This commit is contained in:
parent
77a3adbad2
commit
cefab980e4
|
@ -26,7 +26,6 @@ import org.apache.poi.ss.formula.eval.ValueEval;
|
|||
* Finds the maximum value of a column in an area with given conditions.
|
||||
*
|
||||
* TODO:
|
||||
* - wildcards ? and * in string conditions
|
||||
* - functions as conditions
|
||||
*/
|
||||
public final class DMax implements IDStarAlgorithm {
|
||||
|
|
|
@ -26,7 +26,6 @@ import org.apache.poi.ss.formula.eval.ValueEval;
|
|||
* Finds the minimum value of a column in an area with given conditions.
|
||||
*
|
||||
* TODO:
|
||||
* - wildcards ? and * in string conditions
|
||||
* - functions as conditions
|
||||
*/
|
||||
public final class DMin implements IDStarAlgorithm {
|
||||
|
|
|
@ -18,6 +18,7 @@
|
|||
package org.apache.poi.ss.formula.functions;
|
||||
|
||||
import java.util.function.Supplier;
|
||||
import java.util.regex.Pattern;
|
||||
|
||||
import org.apache.poi.ss.formula.eval.AreaEval;
|
||||
import org.apache.poi.ss.formula.eval.BlankEval;
|
||||
|
@ -40,7 +41,6 @@ import org.apache.poi.util.LocaleUtil;
|
|||
* entries against the set of conditions is done here.
|
||||
*
|
||||
* TODO:
|
||||
* - wildcards ? and * in string conditions
|
||||
* - functions as conditions
|
||||
*/
|
||||
@Internal
|
||||
|
@ -351,10 +351,16 @@ public final class DStarRunner implements Function3Arg {
|
|||
} else { // It's a text starts-with condition.
|
||||
if(conditionString.isEmpty()) {
|
||||
return value instanceof StringEval;
|
||||
}
|
||||
else {
|
||||
} else {
|
||||
String valueString = value instanceof BlankEval ? "" : OperandResolver.coerceValueToString(value);
|
||||
return valueString.toLowerCase(LocaleUtil.getUserLocale()).startsWith(conditionString.toLowerCase(LocaleUtil.getUserLocale()));
|
||||
final String lowerValue = valueString.toLowerCase(LocaleUtil.getUserLocale());
|
||||
final String lowerCondition = conditionString.toLowerCase(LocaleUtil.getUserLocale());
|
||||
final Pattern pattern = Countif.StringMatcher.getWildCardPattern(lowerCondition);
|
||||
if (pattern == null) {
|
||||
return lowerValue.startsWith(lowerCondition);
|
||||
} else {
|
||||
return pattern.matcher(lowerValue).matches();
|
||||
}
|
||||
}
|
||||
}
|
||||
} else if(condition instanceof NumericValueEval) {
|
||||
|
|
|
@ -26,7 +26,6 @@ import org.apache.poi.ss.formula.eval.ValueEval;
|
|||
* Finds the total value of matching values in a column in an area with given conditions.
|
||||
*
|
||||
* TODO:
|
||||
* - wildcards ? and * in string conditions
|
||||
* - functions as conditions
|
||||
*/
|
||||
public final class DSum implements IDStarAlgorithm {
|
||||
|
|
|
@ -38,7 +38,7 @@ public class TestDGet {
|
|||
//https://support.microsoft.com/en-us/office/dget-function-455568bf-4eef-45f7-90f0-ec250d00892e
|
||||
@Test
|
||||
void testMicrosoftExample1() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, false)) {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "=Apple")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
|
@ -49,7 +49,7 @@ public class TestDGet {
|
|||
|
||||
@Test
|
||||
void testMicrosoftExample1CaseInsensitive() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, true)) {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "=apple")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
|
@ -58,9 +58,63 @@ public class TestDGet {
|
|||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testMicrosoftExample1StartsWith() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "App")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, \"Yield\", A1:F3)", 10);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, 4, A1:F3)", 10);
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testMicrosoftExample1StartsWithLowercase() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "app")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, \"Yield\", A1:F3)", 10);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, 4, A1:F3)", 10);
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testMicrosoftExample1Wildcard() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "A*le")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, \"Yield\", A1:F3)", 10);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, 4, A1:F3)", 10);
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testMicrosoftExample1WildcardLowercase() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "a*le")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, \"Yield\", A1:F3)", 10);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, 4, A1:F3)", 10);
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testMicrosoftExample1AppleWildcardNoMatch() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(false, "A*x")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:A3)", FormulaError.NUM);
|
||||
assertError(fe, cell, "DGET(A5:E11, \"Yield\", A1:F3)", FormulaError.VALUE);
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
void testMicrosoftExample1Variant() throws IOException {
|
||||
try (HSSFWorkbook wb = initWorkbook1(true, false)) {
|
||||
try (HSSFWorkbook wb = initWorkbook1(true, "=Apple")) {
|
||||
HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
|
||||
HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
|
||||
assertDouble(fe, cell, "DGET(A5:E11, \"Yield\", A1:F3)", 6);
|
||||
|
@ -68,11 +122,10 @@ public class TestDGet {
|
|||
}
|
||||
}
|
||||
|
||||
private HSSFWorkbook initWorkbook1(boolean adjustAppleCondition, boolean lowercase) {
|
||||
private HSSFWorkbook initWorkbook1(boolean adjustAppleCondition, String appleCondition) {
|
||||
HSSFWorkbook wb = new HSSFWorkbook();
|
||||
HSSFSheet sheet = wb.createSheet();
|
||||
addRow(sheet, 0, "Tree", "Height", "Age", "Yield", "Profit", "Height");
|
||||
String appleCondition = lowercase ? "=apple" : "=Apple";
|
||||
if (adjustAppleCondition) {
|
||||
addRow(sheet, 1, appleCondition, ">=8", null, null, null, "<12");
|
||||
} else {
|
||||
|
|
Loading…
Reference in New Issue