From 988a5583ddff478c75ad03e5fcce67b507932861 Mon Sep 17 00:00:00 2001 From: Yegor Kozlov Date: Thu, 12 Aug 2010 14:14:26 +0000 Subject: [PATCH] added support for RANDBETWEEN(), see Bugzilla 48526 git-svn-id: https://svn.apache.org/repos/asf/poi/trunk@984796 13f79535-47bb-0310-9956-ffa450edef68 --- src/documentation/content/xdocs/status.xml | 1 + .../record/formula/atp/AnalysisToolPak.java | 2 +- .../hssf/record/formula/atp/RandBetween.java | 85 ++++++++ .../record/formula/atp/TestRandBetween.java | 194 ++++++++++++++++++ test-data/spreadsheet/TestRandBetween.xls | Bin 0 -> 17408 bytes 5 files changed, 281 insertions(+), 1 deletion(-) create mode 100644 src/java/org/apache/poi/hssf/record/formula/atp/RandBetween.java create mode 100644 src/testcases/org/apache/poi/hssf/record/formula/atp/TestRandBetween.java create mode 100644 test-data/spreadsheet/TestRandBetween.xls diff --git a/src/documentation/content/xdocs/status.xml b/src/documentation/content/xdocs/status.xml index 56de7a091..0b791f101 100644 --- a/src/documentation/content/xdocs/status.xml +++ b/src/documentation/content/xdocs/status.xml @@ -34,6 +34,7 @@ + 48526 - added implementation for RANDBETWEEN() 49725 - avoid exception in OperandResolver.parseDouble when input is minus ("-") 49723 - fixed OperandResolver to correctly handle inputs with leading decimal place initial support for Excel autofilter diff --git a/src/java/org/apache/poi/hssf/record/formula/atp/AnalysisToolPak.java b/src/java/org/apache/poi/hssf/record/formula/atp/AnalysisToolPak.java index 61f108b67..76e4edfed 100644 --- a/src/java/org/apache/poi/hssf/record/formula/atp/AnalysisToolPak.java +++ b/src/java/org/apache/poi/hssf/record/formula/atp/AnalysisToolPak.java @@ -138,7 +138,7 @@ public final class AnalysisToolPak implements UDFFinder { r(m, "PRICEDISC", null); r(m, "PRICEMAT", null); r(m, "QUOTIENT", null); - r(m, "RAND BETWEEN", null); + r(m, "RANDBETWEEN", RandBetween.instance); r(m, "RECEIVED", null); r(m, "SERIESSUM", null); r(m, "SQRTPI", null); diff --git a/src/java/org/apache/poi/hssf/record/formula/atp/RandBetween.java b/src/java/org/apache/poi/hssf/record/formula/atp/RandBetween.java new file mode 100644 index 000000000..43b6c373b --- /dev/null +++ b/src/java/org/apache/poi/hssf/record/formula/atp/RandBetween.java @@ -0,0 +1,85 @@ +/* ==================================================================== + 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.hssf.record.formula.atp; + +import org.apache.poi.hssf.record.formula.eval.ErrorEval; +import org.apache.poi.hssf.record.formula.eval.EvaluationException; +import org.apache.poi.hssf.record.formula.eval.NumberEval; +import org.apache.poi.hssf.record.formula.eval.OperandResolver; +import org.apache.poi.hssf.record.formula.eval.ValueEval; +import org.apache.poi.hssf.record.formula.functions.FreeRefFunction; +import org.apache.poi.ss.formula.OperationEvaluationContext; + +/** + * Implementation of Excel 'Analysis ToolPak' function RANDBETWEEN()
+ * + * Returns a random integer number between the numbers you specify.

+ * + * Syntax
+ * RANDBETWEEN(bottom, top)

+ * + * bottom is the smallest integer RANDBETWEEN will return.
+ * top is the largest integer RANDBETWEEN will return.
+ + * @author Brendan Nolan + */ +final class RandBetween implements FreeRefFunction{ + + public static final FreeRefFunction instance = new RandBetween(); + + private RandBetween() { + //enforces singleton + } + + /** + * Evaluate for RANDBETWEEN(). Must be given two arguments. Bottom must be greater than top. + * Bottom is rounded up and top value is rounded down. After rounding top has to be set greater + * than top. + * + * @see org.apache.poi.hssf.record.formula.functions.FreeRefFunction#evaluate(org.apache.poi.hssf.record.formula.eval.ValueEval[], org.apache.poi.ss.formula.OperationEvaluationContext) + */ + @Override + public ValueEval evaluate(ValueEval[] args, OperationEvaluationContext ec) { + + double bottom, top; + + if (args.length != 2) { + return ErrorEval.VALUE_INVALID; + } + + try { + bottom = OperandResolver.coerceValueToDouble(OperandResolver.getSingleValue(args[0], ec.getRowIndex(), ec.getColumnIndex())); + top = OperandResolver.coerceValueToDouble(OperandResolver.getSingleValue(args[1], ec.getRowIndex(), ec.getColumnIndex())); + if(bottom > top) { + return ErrorEval.NUM_ERROR; + } + } catch (EvaluationException e) { + return ErrorEval.VALUE_INVALID; + } + + bottom = Math.ceil(bottom); + top = Math.floor(top); + + if(bottom > top) { + top = bottom; + } + + return new NumberEval((bottom + (int)(Math.random() * ((top - bottom) + 1)))); + + } + +} diff --git a/src/testcases/org/apache/poi/hssf/record/formula/atp/TestRandBetween.java b/src/testcases/org/apache/poi/hssf/record/formula/atp/TestRandBetween.java new file mode 100644 index 000000000..1cd0db22d --- /dev/null +++ b/src/testcases/org/apache/poi/hssf/record/formula/atp/TestRandBetween.java @@ -0,0 +1,194 @@ +/* ==================================================================== + 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.hssf.record.formula.atp; + +import junit.framework.TestCase; + +import org.apache.poi.hssf.HSSFTestDataSamples; +import org.apache.poi.hssf.record.formula.eval.ErrorEval; +import org.apache.poi.hssf.usermodel.HSSFCell; +import org.apache.poi.ss.usermodel.Cell; +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; + +/** + * Testcase for 'Analysis Toolpak' function RANDBETWEEN() + * + * @author Brendan Nolan + */ +public class TestRandBetween extends TestCase { + + private Workbook wb; + private FormulaEvaluator evaluator; + private Cell bottomValueCell; + private Cell topValueCell; + private Cell formulaCell; + + @Override + protected void setUp() throws Exception { + super.setUp(); + wb = HSSFTestDataSamples.openSampleWorkbook("TestRandBetween.xls"); + evaluator = wb.getCreationHelper().createFormulaEvaluator(); + + Sheet sheet = wb.createSheet("RandBetweenSheet"); + Row row = sheet.createRow(0); + bottomValueCell = row.createCell(0); + topValueCell = row.createCell(1); + formulaCell = row.createCell(2, HSSFCell.CELL_TYPE_FORMULA); + } + + @Override + protected void tearDown() throws Exception { + // TODO Auto-generated method stub + super.tearDown(); + } + + /** + * Check where values are the same + */ + public void testRandBetweenSameValues() { + + evaluator.clearAllCachedResultValues(); + formulaCell.setCellFormula("RANDBETWEEN(1,1)"); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(1, formulaCell.getNumericCellValue(), 0); + evaluator.clearAllCachedResultValues(); + formulaCell.setCellFormula("RANDBETWEEN(-1,-1)"); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(-1, formulaCell.getNumericCellValue(), 0); + + } + + /** + * Check special case where rounded up bottom value is greater than + * top value. + */ + public void testRandBetweenSpecialCase() { + + + bottomValueCell.setCellValue(0.05); + topValueCell.setCellValue(0.1); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(1, formulaCell.getNumericCellValue(), 0); + bottomValueCell.setCellValue(-0.1); + topValueCell.setCellValue(-0.05); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(0, formulaCell.getNumericCellValue(), 0); + bottomValueCell.setCellValue(-1.1); + topValueCell.setCellValue(-1.05); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(-1, formulaCell.getNumericCellValue(), 0); + bottomValueCell.setCellValue(-1.1); + topValueCell.setCellValue(-1.1); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(-1, formulaCell.getNumericCellValue(), 0); + } + + /** + * Check top value of BLANK which Excel will evaluate as 0 + */ + public void testRandBetweenTopBlank() { + + bottomValueCell.setCellValue(-1); + topValueCell.setCellType(Cell.CELL_TYPE_BLANK); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertTrue(formulaCell.getNumericCellValue() == 0 || formulaCell.getNumericCellValue() == -1); + + } + /** + * Check where input values are of wrong type + */ + public void testRandBetweenWrongInputTypes() { + // Check case where bottom input is of the wrong type + bottomValueCell.setCellValue("STRING"); + topValueCell.setCellValue(1); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(Cell.CELL_TYPE_ERROR, formulaCell.getCachedFormulaResultType()); + assertEquals(ErrorEval.VALUE_INVALID.getErrorCode(), formulaCell.getErrorCellValue()); + + + // Check case where top input is of the wrong type + bottomValueCell.setCellValue(1); + topValueCell.setCellValue("STRING"); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(Cell.CELL_TYPE_ERROR, formulaCell.getCachedFormulaResultType()); + assertEquals(ErrorEval.VALUE_INVALID.getErrorCode(), formulaCell.getErrorCellValue()); + + // Check case where both inputs are of wrong type + bottomValueCell.setCellValue("STRING"); + topValueCell.setCellValue("STRING"); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(Cell.CELL_TYPE_ERROR, formulaCell.getCachedFormulaResultType()); + assertEquals(ErrorEval.VALUE_INVALID.getErrorCode(), formulaCell.getErrorCellValue()); + + } + + /** + * Check case where bottom is greater than top + */ + public void testRandBetweenBottomGreaterThanTop() { + + // Check case where bottom is greater than top + bottomValueCell.setCellValue(1); + topValueCell.setCellValue(0); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(Cell.CELL_TYPE_ERROR, formulaCell.getCachedFormulaResultType()); + assertEquals(ErrorEval.NUM_ERROR.getErrorCode(), formulaCell.getErrorCellValue()); + bottomValueCell.setCellValue(1); + topValueCell.setCellType(Cell.CELL_TYPE_BLANK); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertEquals(Cell.CELL_TYPE_ERROR, formulaCell.getCachedFormulaResultType()); + assertEquals(ErrorEval.NUM_ERROR.getErrorCode(), formulaCell.getErrorCellValue()); + } + + /** + * Boundary check of Double MIN and MAX values + */ + public void testRandBetweenBoundaryCheck() { + + bottomValueCell.setCellValue(Double.MIN_VALUE); + topValueCell.setCellValue(Double.MAX_VALUE); + formulaCell.setCellFormula("RANDBETWEEN($A$1,$B$1)"); + evaluator.clearAllCachedResultValues(); + evaluator.evaluateFormulaCell(formulaCell); + assertTrue(formulaCell.getNumericCellValue() >= Double.MIN_VALUE && formulaCell.getNumericCellValue() <= Double.MAX_VALUE); + + } + +} diff --git a/test-data/spreadsheet/TestRandBetween.xls b/test-data/spreadsheet/TestRandBetween.xls new file mode 100644 index 0000000000000000000000000000000000000000..f99bb2651b82675f2fa43fab78f2d74d583d19d3 GIT binary patch literal 17408 zcmeHO3vg7`8UF8PlWYi&1VVU+HQ`MXLlO`KSsvn}hQ}xlcGQ6oHjok%8WRgMFvQkQ zXR39ORH%^Fq1Kt!XGQCywKa4)+K#bxTB*fq2RrI$?X*Jev^vQ4`_9?Bd-v?Um%F2N zisit$x%a>4eE)y`|3CkE+_NwKru6usN5;P{Mp`U+ayn5Y1rEA}duEkNL?+>e&!-cK zgeHpM_FOuPH1H8*oebmUA%~Ikk!kZn?l8Wcmto)Ny|nsp~T*>Xp)of87$571DvfU9tm~37*Q~F}6}d zs1}XzDl(w1atZ&u_~0LQm&||OI==Ir=lQn+v|e3I)`5GMY?X~lj;*>@4%d+qvgo(A z3_+@r^{_@=GGDHe9=QSknpN8`hZb6uOr&&68}2)NKxcqIV<7tvW$-DQ@#>e!r+m2> z99onNab@7Z>EqeUo1({1u{k0baf?A^BnW2(BW3M!rtA z@jm)#re#WoW{WZmK*1MT1&}TTJ@?~Ug1Evrus*J%)b(Li_Gxv!2yfnl?T#+^+~oNv z!Ex%E&=OVd8|qrAuETM)FuTFc=H?LgZI4{4MCwGu^V zl(g&&B`j%_r>RKK)>;?`{7Zxo@z12OQr{BQ=tuK?xrEPH;#FAFAA`1C>?;RLG@h}< zqBE4RB<93X~_5ne08)iP72i>$Ai6|JhSs;XOGv+z2{J?WJ-m7uP# zS+c&SBHRO=&-WHg%dgp_O_C{|vkXgWv$2d8G6p}>2)x>YHp*-{-yvviU52dsF)3~= zW(#~=&EQ1-sb**B1}Y6iN$0%q9Q~8i166Cmim4Pb^!!-zP5ACi{io;;deHClpg-h6 zKj=Y!*n|Fn2mRX~^jkgXUh;V1KdNxJHc@_<(!+N==vtoa@>-s3`u99=9`T?*=0X3N z2mR|F^rt-Nxyth+g;SWNAMGbx%PGBmv$S-7@%~~7?^ETuzSH#9)@LR^Gg-na6wLf$1spv1s8r)*Zs>^dd>Y$^# zrgM#&q(^a!<*Gq9_;Nj~%BS?B{hw>xB+drhVkxU}xb9W-l$`e`^_HafmzI_nmqX77 z6rF2i8(-^L>pveeD@8Z-%=NUQ8*-M}^p`LxmBlGNaNTW|-x(>BoiuzZEtUz-oIJ5B zQX{)E=qwPz+P+M!V=O$WF#*Hba76x4b_Ev6se+zf=D>jqs+>4*Rg+T%4rw`6V9dy= zLSe2IXq22du>0mzf&DJ03haRqu+JAPf-!KV%4UEVYZ9x}%g-FNC6 z{H?=J3jsj(VOG;z~$K-f9phpN#bvv^MZl+Tcr4#>;%}X4!9e`2Gd&oHzjbD$KsaCOmx4sbJdAyZFA~rFI+3={9me1_6D11O z;Ki~Z?h<#9lP6E6KnjzjfDg z{c#WXNW9zc05N;}{FHjA%dGWeDvl)vQy_K-I(+zWR&OWG?CqohTP3@G7NJ7edo4q~n_bn}eeK~O zTat@XlF;2?j7)v@g+}5#9Ts=>byK4?(WNad@s92}dm}4lFGtd3vceUKVN#F%`>7Je z4t7+Q;%jINzBlk|v<@>CP97A7a*EY`moV~NU_O} zx1N0MRd+TcO*ReLY^M3J(VYxOm$6K5U$xHrVv|Yj3-=nP9SU@w5gXHcn3)Y&v!H zF?Ti-$!4Cvr$xbLUI0(4Z@BZ(mo*y(G^A8an`E+a@w6#EY@D7}-*9aIo$hQZOg1i_ zHp7RF)6?o3e*XId?rbKTY+O98+J}wP)9M=zA9~K6P1I!L;%Rk0Y@D7}-_Z9$GD4fS zInQL{;%SXOY@D7}-|*qU9=FyE#TQn z0Cjp1K7FiN=?*$24GRA;L8ls^PM;Au_><4OgHBC@!dpzxnFgrSLvXxo(|6rLr=>yR z8zyLt0qXPzkt-f})*W zc0i{Oz7?vO1VK45wi$3&K`|)6X;8l8s>XsEoKKOAr=pCfzR(Dq+Q8R{O*uEj`jJ*%iXHN9cf znP$`pCnBiRgA-<5YVO;TJcmgxwY`O?QESvFObpGck;!W`&Vb-c#)|FR+M7F?yF0sf zMAyc*ckhi{nh6z}n<&BY&+RzoN85KO`}0`l4(NO>#Musi;4;OwK8>ApuOhS!3-n7n zJK?AcGjXl)iLhJ>rF9yv%Dn{}3(Rb+;h67Zf9$e&^QN|r%~7ls3_Q8jeMV101o>1TS>~*YVE-JQ4f;z@N|%f;Tw9 z5d%%|kuKmm4tjv=sX<7AH#)%)3ypw~H_8Q^@lac=(5aTb&=8r+(>#}VZ0mt5^kkYW zREGBO4D2@eB8{HzXxz)Njm8a+kJV74YAFs}kITiOMmVqnoL8Wm5m!(q3# zAKM^Fhlfk`3c6!MrmU8L)W+LVR^k+E{XA(wV-y}@@64wB#Fc*lCT!PPBkwjRO}eM_thtJKdz z_@-E{T)OJwWh>UMTd`tQNG6V95%j(A7%-)Pr|~Nh4S&Rn$PwI5de@Ru>NhC_fT~a~ zA}x_}WKH3<92xx!@Ag5UeU3NF-n8T(Xa^lMa<~n&+Z;5II4==>GQK3^WPEX`jIUK< z-8yWhA4DDoe(bCvm|}#wFU6I=kcr5tADsB@%8hGc>lJ;LqR&>>FDpu~qfJxMMeya@ zx*2bdgvo0(@>f*pThw(LO1G-?R&2WCentxA?buAm{UNL(hzRxLUs$Mx29{RJZG_|{ z8LAeGY>tdUwky#y)DI@|F7`9C7T&Hj3ccX$F)T&yEI8W71imri3uGBhfF8fA#K@AFSR|a{nC>nLYi{W0>g3w~*-@e7^*l^Oehx zIl!((9*MjGne&6~$k;2FTaZT~??I-oy@5(Ro5i|J<~;}Bm2E9uoi}#2c1KriZ;7|- zfq!7VtYYgly|U%Rf}r2ify)1%O$Wy4Mr-^lg3mwn2uX zAi=3r3bn4YYwL}i;oqq0oBFbnJ5}4T2HYrLK!w~Ae}U=j4MA#Ce_cTe1}u{+|A4T8 zi=EB