]> source.dussan.org Git - poi.git/commitdiff
[bug-49202] add PERCENTRANK.EXC function
authorPJ Fanning <fanningpj@apache.org>
Sat, 7 Aug 2021 19:28:33 +0000 (19:28 +0000)
committerPJ Fanning <fanningpj@apache.org>
Sat, 7 Aug 2021 19:28:33 +0000 (19:28 +0000)
git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@1892090 13f79535-47bb-0310-9956-ffa450edef68

poi/src/main/java/org/apache/poi/ss/formula/atp/PercentRankExcFunction.java
poi/src/main/java/org/apache/poi/ss/formula/functions/PercentRank.java
poi/src/test/java/org/apache/poi/ss/formula/atp/TestPercentRankExcFunction.java
poi/src/test/java/org/apache/poi/ss/formula/atp/TestPercentRankIncFunction.java

index 8391666615704a837b5973e3a32ada07b37a64bb..7968ed13f2463506bb8ebe2b8afe3ef62372287a 100644 (file)
@@ -135,13 +135,13 @@ final class PercentRankExcFunction implements FreeRefFunction {
                 if (d < x) lessThanCount++;
             }
             BigDecimal result = new BigDecimal((double)(lessThanCount + 1) / (double)(numbers.size() + 1));
-            return new NumberEval(PercentRank.round(result, significance, RoundingMode.DOWN));
+            return new NumberEval(PercentRank.round(result, significance));
         } else {
-            ValueEval belowRank = calculateRank(numbers, closestMatchBelow, significance, false);
+            ValueEval belowRank = calculateRank(numbers, closestMatchBelow, significance + 3, false);
             if (!(belowRank instanceof NumberEval)) {
                 return belowRank;
             }
-            ValueEval aboveRank = calculateRank(numbers, closestMatchAbove, significance, false);
+            ValueEval aboveRank = calculateRank(numbers, closestMatchAbove, significance + 3, false);
             if (!(aboveRank instanceof NumberEval)) {
                 return aboveRank;
             }
index 10d67f7cc8c9a43b86464daf8f72b233df8e35c1..1f4530b921964877634c6d6f4a66edf32b21355b 100644 (file)
@@ -18,6 +18,7 @@
 package org.apache.poi.ss.formula.functions;
 
 import org.apache.poi.ss.formula.eval.*;
+import org.apache.poi.ss.util.NumberToTextConverter;
 import org.apache.poi.util.Internal;
 
 import java.math.BigDecimal;
@@ -123,13 +124,13 @@ public final class PercentRank implements Function {
                 return ErrorEval.NA;
             }
             BigDecimal result = new BigDecimal((double)lessThanCount / (double)(lessThanCount + greaterThanCount));
-            return new NumberEval(round(result, significance, RoundingMode.DOWN));
+            return new NumberEval(round(result, significance));
         } else {
-            ValueEval belowRank = calculateRank(numbers, closestMatchBelow, significance, false);
+            ValueEval belowRank = calculateRank(numbers, closestMatchBelow, significance + 3, false);
             if (!(belowRank instanceof NumberEval)) {
                 return belowRank;
             }
-            ValueEval aboveRank = calculateRank(numbers, closestMatchAbove, significance, false);
+            ValueEval aboveRank = calculateRank(numbers, closestMatchAbove, significance + 3, false);
             if (!(aboveRank instanceof NumberEval)) {
                 return aboveRank;
             }
@@ -142,16 +143,17 @@ public final class PercentRank implements Function {
                                          NumberEval belowRank, NumberEval aboveRank, int significance) {
         double diff = closestMatchAbove - closestMatchBelow;
         double pos = x - closestMatchBelow;
-        double rankDiff = aboveRank.getNumberValue() - belowRank.getNumberValue();
-        BigDecimal result = new BigDecimal(belowRank.getNumberValue() + (rankDiff * (pos / diff)));
-        return new NumberEval(round(result, significance, RoundingMode.HALF_UP));
+        BigDecimal rankDiff = new BigDecimal(NumberToTextConverter.toText(aboveRank.getNumberValue() - belowRank.getNumberValue()));
+        BigDecimal result = new BigDecimal(belowRank.getNumberValue()).add(rankDiff.multiply(new BigDecimal(pos / diff)));
+        return new NumberEval(round(result, significance));
     }
 
     @Internal
-    public static double round(BigDecimal bd, int significance, RoundingMode rounding) {
+    public static double round(BigDecimal bd, int significance) {
         //the rounding in https://support.microsoft.com/en-us/office/percentrank-function-f1b5836c-9619-4847-9fc9-080ec9024442
         //is very inconsistent, this hodge podge of rounding modes is the only way to match Excel results
-        return bd.setScale(significance, rounding).doubleValue();
+        BigDecimal bd2 = bd.setScale(significance + 3, RoundingMode.HALF_UP);
+        return bd2.setScale(significance, RoundingMode.DOWN).doubleValue();
     }
 
     @Internal
index 10297de357014dfd71f2392a0e6d8fab3ab0726e..49123108683f13ac19d838e5dfd0db5642658caf 100644 (file)
@@ -38,7 +38,7 @@ public class TestPercentRankExcFunction {
 
     // PERCENTRANK.INC test case (for comparison)
     @Test
-    void testMicrosoftExample1() throws IOException {
+    void testPercentRankIncExample1() throws IOException {
         try (HSSFWorkbook wb = initWorkbook1()) {
             HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
             HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
@@ -53,6 +53,18 @@ public class TestPercentRankExcFunction {
         }
     }
 
+    //https://support.microsoft.com/en-us/office/percentrank-exc-function-d8afee96-b7e2-4a2f-8c01-8fcdedaa6314
+    @Test
+    void testMicrosoftExample1() throws IOException {
+        try (HSSFWorkbook wb = initWorkbook2()) {
+            HSSFFormulaEvaluator fe = new HSSFFormulaEvaluator(wb);
+            HSSFCell cell = wb.getSheetAt(0).getRow(0).createCell(100);
+            assertDouble(fe, cell, "PERCENTRANK.EXC(A2:A10, 7)", 0.7);
+            assertDouble(fe, cell, "PERCENTRANK.EXC(A2:A10,5.43)", 0.381);
+            assertDouble(fe, cell, "PERCENTRANK.EXC(A2:A10,5.43,1)", 0.3);
+        }
+    }
+
     @Test
     void testErrorCases() throws IOException {
         try (HSSFWorkbook wb = initWorkbook1()) {
@@ -82,6 +94,22 @@ public class TestPercentRankExcFunction {
         return wb;
     }
 
+    private HSSFWorkbook initWorkbook2() {
+        HSSFWorkbook wb = new HSSFWorkbook();
+        HSSFSheet sheet = wb.createSheet();
+        addRow(sheet, 0, "Data");
+        addRow(sheet, 1, 1);
+        addRow(sheet, 2, 2);
+        addRow(sheet, 3, 3);
+        addRow(sheet, 4, 6);
+        addRow(sheet, 5, 6);
+        addRow(sheet, 6, 6);
+        addRow(sheet, 7, 7);
+        addRow(sheet, 8, 8);
+        addRow(sheet, 9, 9);
+        return wb;
+    }
+
     private static void confirmErrorResult(HSSFFormulaEvaluator fe, HSSFCell cell, String formulaText, FormulaError expectedResult) {
         cell.setCellFormula(formulaText);
         fe.notifyUpdateCell(cell);
index 596e6844cbb8bd49879c962df01894b4e121097d..d594f5d717608f300dffed238b91278e42434853 100644 (file)
@@ -48,6 +48,7 @@ public class TestPercentRankIncFunction {
             assertDouble(fe, cell, "PERCENTRANK.INC(A2:A11,8,2)", 0.66);
             assertDouble(fe, cell, "PERCENTRANK.INC(A2:A11,8,4)", 0.6666);
             assertDouble(fe, cell, "PERCENTRANK.INC(A2:A11,5)", 0.583);
+            assertDouble(fe, cell, "PERCENTRANK.INC(A2:A11,5,5)", 0.58333);
             assertDouble(fe, cell, "PERCENTRANK.INC(A2:A11,1)", 0);
             assertDouble(fe, cell, "PERCENTRANK.INC(A2:A11,13)", 1);
         }