From 9b44cf34182c6bfb4ea9a71871ef23fb5ac241ea Mon Sep 17 00:00:00 2001 From: Mark Baker Date: Sun, 22 Jul 2018 19:17:04 +0100 Subject: [PATCH] Add further new Functions introduced in MS Excel 2013 and 2016 (#608) - Fix ISFORMULA() function to work with a cell reference to another worksheet - Added calculation engine support for the new functions that were added in MS Excel 2013 and MS Excel 2016 - Text Functions - CONCAT() Synonym for CONCATENATE() - NUMBERVALUE() Converts text to a number, in a locale-independent way - UNICHAR() Synonym for CHAR() in PHPSpreadsheet, which has always used UTF-8 internally - UNIORD() Synonym for ORD() in PHPSpreadsheet, which has always used UTF-8 internally - TEXTJOIN() Joins together two or more text strings, separated by a delimiter - Logical Functions - XOR() Returns a logical Exclusive Or of all arguments - Date/Time Functions - ISOWEEKNUM() Returns the ISO 8601 week number of the year for a given date - Lookup and Reference Functions - FORMULATEXT() Returns a formula as a string - Engineering Functions - ERF.PRECISE() Returns the error function integrated between 0 and a supplied limit - ERFC.PRECISE() Synonym for ERFC - Math and Trig Functions - SEC() Returns the secant of an angle - SECH() Returns the hyperbolic secant of an angle - CSC() Returns the cosecant of an angle - CSCH() Returns the hyperbolic cosecant of an angle - COT() Returns the cotangent of an angle - COTH() Returns the hyperbolic cotangent of an angle - ACOT() Returns the cotangent of an angle - ACOTH() Returns the hyperbolic cotangent of an angle - Financial Functions - PDURATION() Calculates the number of periods required for an investment to reach a specified value - RRI() Calculates the interest rate required for an investment to grow to a specified future value --- CHANGELOG.md | 29 +++ docs/references/function-list-by-category.md | 38 +++- docs/references/function-list-by-name.md | 39 +++- .../Calculation/Calculation.php | 112 ++++++++++ src/PhpSpreadsheet/Calculation/DateTime.php | 57 +++-- .../Calculation/Engineering.php | 25 ++- src/PhpSpreadsheet/Calculation/Financial.php | 108 +++++++--- src/PhpSpreadsheet/Calculation/Functions.php | 15 +- src/PhpSpreadsheet/Calculation/Logical.php | 149 ++++++++----- src/PhpSpreadsheet/Calculation/LookupRef.php | 29 +++ src/PhpSpreadsheet/Calculation/MathTrig.php | 178 +++++++++++++++- src/PhpSpreadsheet/Calculation/TextData.php | 74 +++++++ .../Calculation/functionlist.txt | 21 ++ .../Calculation/DateTimeTest.php | 17 ++ .../Calculation/EngineeringTest.php | 16 ++ .../Calculation/FinancialTest.php | 96 +++++++++ .../Calculation/FunctionsTest.php | 69 +++++- .../Calculation/LogicalTest.php | 16 ++ .../Calculation/LookupRefTest.php | 58 +++++ .../Calculation/MathTrigTest.php | 200 ++++++++++++++++++ .../Calculation/TextDataTest.php | 45 ++++ tests/data/Calculation/DateTime/DATEVALUE.php | 4 + .../data/Calculation/DateTime/ISOWEEKNUM.php | 36 ++++ .../Calculation/Engineering/ERFPRECISE.php | 22 ++ tests/data/Calculation/Financial/COUPDAYS.php | 21 ++ .../data/Calculation/Financial/PDURATION.php | 36 ++++ .../data/Calculation/Financial/PRICEDISC.php | 12 ++ tests/data/Calculation/Financial/PV.php | 24 +++ tests/data/Calculation/Financial/RRI.php | 28 +++ tests/data/Calculation/Financial/SLN.php | 40 ++++ tests/data/Calculation/Financial/SYD.php | 44 ++++ .../data/Calculation/Functions/ISFORMULA.php | 27 ++- tests/data/Calculation/Logical/AND.php | 2 +- tests/data/Calculation/Logical/XOR.php | 52 +++++ .../Calculation/LookupRef/FORMULATEXT.php | 34 +++ tests/data/Calculation/MathTrig/ACOT.php | 60 ++++++ tests/data/Calculation/MathTrig/ACOTH.php | 60 ++++++ tests/data/Calculation/MathTrig/COT.php | 44 ++++ tests/data/Calculation/MathTrig/COTH.php | 60 ++++++ tests/data/Calculation/MathTrig/CSC.php | 44 ++++ tests/data/Calculation/MathTrig/CSCH.php | 60 ++++++ tests/data/Calculation/MathTrig/ROMAN.php | 4 + tests/data/Calculation/MathTrig/SEC.php | 60 ++++++ tests/data/Calculation/MathTrig/SECH.php | 60 ++++++ .../Calculation/MathTrig/SUBTOTALNESTED.php | 1 + .../data/Calculation/MathTrig/SUMPRODUCT.php | 19 ++ tests/data/Calculation/MathTrig/SUMX2MY2.php | 19 ++ tests/data/Calculation/MathTrig/SUMX2PY2.php | 19 ++ tests/data/Calculation/MathTrig/SUMXMY2.php | 19 ++ .../data/Calculation/TextData/NUMBERVALUE.php | 52 +++++ tests/data/Calculation/TextData/TEXTJOIN.php | 28 +++ 51 files changed, 2261 insertions(+), 121 deletions(-) create mode 100644 tests/data/Calculation/DateTime/ISOWEEKNUM.php create mode 100644 tests/data/Calculation/Engineering/ERFPRECISE.php create mode 100644 tests/data/Calculation/Financial/PDURATION.php create mode 100644 tests/data/Calculation/Financial/PRICEDISC.php create mode 100644 tests/data/Calculation/Financial/PV.php create mode 100644 tests/data/Calculation/Financial/RRI.php create mode 100644 tests/data/Calculation/Financial/SLN.php create mode 100644 tests/data/Calculation/Financial/SYD.php create mode 100644 tests/data/Calculation/Logical/XOR.php create mode 100644 tests/data/Calculation/LookupRef/FORMULATEXT.php create mode 100644 tests/data/Calculation/MathTrig/ACOT.php create mode 100644 tests/data/Calculation/MathTrig/ACOTH.php create mode 100644 tests/data/Calculation/MathTrig/COT.php create mode 100644 tests/data/Calculation/MathTrig/COTH.php create mode 100644 tests/data/Calculation/MathTrig/CSC.php create mode 100644 tests/data/Calculation/MathTrig/CSCH.php create mode 100644 tests/data/Calculation/MathTrig/SEC.php create mode 100644 tests/data/Calculation/MathTrig/SECH.php create mode 100644 tests/data/Calculation/MathTrig/SUMPRODUCT.php create mode 100644 tests/data/Calculation/MathTrig/SUMX2MY2.php create mode 100644 tests/data/Calculation/MathTrig/SUMX2PY2.php create mode 100644 tests/data/Calculation/MathTrig/SUMXMY2.php create mode 100644 tests/data/Calculation/TextData/NUMBERVALUE.php create mode 100644 tests/data/Calculation/TextData/TEXTJOIN.php diff --git a/CHANGELOG.md b/CHANGELOG.md index 5bd4ae11..dd729183 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -12,6 +12,35 @@ and this project adheres to [Semantic Versioning](http://semver.org/). - Add excel function EXACT(value1, value2) support - [595](https://github.com/PHPOffice/PhpSpreadsheet/pull/595) - Support workbook view attributes for Xlsx format - [#523](https://github.com/PHPOffice/PhpSpreadsheet/issues/523) - Read and write hyperlink for drawing image - [#490](https://github.com/PHPOffice/PhpSpreadsheet/pull/490) +- Fix ISFORMULA() function to work with a cell reference to another worksheet +- Added calculation engine support for the new functions that were added in MS Excel 2013 and MS Excel 2016 + - Text Functions + - CONCAT() Synonym for CONCATENATE() + - NUMBERVALUE() Converts text to a number, in a locale-independent way + - UNICHAR() Synonym for CHAR() in PHPSpreadsheet, which has always used UTF-8 internally + - UNIORD() Synonym for ORD() in PHPSpreadsheet, which has always used UTF-8 internally + - TEXTJOIN() Joins together two or more text strings, separated by a delimiter + - Logical Functions + - XOR() Returns a logical Exclusive Or of all arguments + - Date/Time Functions + - ISOWEEKNUM() Returns the ISO 8601 week number of the year for a given date + - Lookup and Reference Functions + - FORMULATEXT() Returns a formula as a string + - Financial Functions + - PDURATION() Calculates the number of periods required for an investment to reach a specified value + - RRI() Calculates the interest rate required for an investment to grow to a specified future value + - Engineering Functions + - ERF.PRECISE() Returns the error function integrated between 0 and a supplied limit + - ERFC.PRECISE() Synonym for ERFC + - Math and Trig Functions + - SEC() Returns the secant of an angle + - SECH() Returns the hyperbolic secant of an angle + - CSC() Returns the cosecant of an angle + - CSCH() Returns the hyperbolic cosecant of an angle + - COT() Returns the cotangent of an angle + - COTH() Returns the hyperbolic cotangent of an angle + - ACOT() Returns the cotangent of an angle + - ACOTH() Returns the hyperbolic cotangent of an angle ### Fixed diff --git a/docs/references/function-list-by-category.md b/docs/references/function-list-by-category.md index 5561828c..07f64f76 100644 --- a/docs/references/function-list-by-category.md +++ b/docs/references/function-list-by-category.md @@ -41,6 +41,7 @@ DAYS360 | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::DAYS360 EDATE | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::EDATE EOMONTH | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::EOMONTH HOUR | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::HOUROFDAY +ISOWEEKNUM | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::ISOWEEKNUM MINUTE | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::MINUTE MONTH | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::MONTHOFYEAR NETWORKDAYS | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::NETWORKDAYS @@ -73,7 +74,9 @@ DEC2HEX | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::DECTOHE DEC2OCT | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::DECTOOCT DELTA | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::DELTA ERF | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERF +ERF.PRECISE | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERFPRECISE ERFC | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERFC +ERFC.PRECISE | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERFC GESTEP | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::GESTEP HEX2BIN | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::HEXTOBIN HEX2DEC | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::HEXTODEC @@ -137,6 +140,7 @@ ODDFPRICE | **Not yet Implemented** ODDFYIELD | **Not yet Implemented** ODDLPRICE | **Not yet Implemented** ODDLYIELD | **Not yet Implemented** +PDURATION | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PDURATION PMT | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PMT PPMT | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PPMT PRICE | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PRICE @@ -145,6 +149,7 @@ PRICEMAT | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PRICEMAT PV | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PV RATE | \PhpOffice\PhpSpreadsheet\Calculation\Financial::RATE RECEIVED | \PhpOffice\PhpSpreadsheet\Calculation\Financial::RECEIVED +RRI | \PhpOffice\PhpSpreadsheet\Calculation\Financial::RRI SLN | \PhpOffice\PhpSpreadsheet\Calculation\Financial::SLN SYD | \PhpOffice\PhpSpreadsheet\Calculation\Financial::SYD TBILLEQ | \PhpOffice\PhpSpreadsheet\Calculation\Financial::TBILLEQ @@ -169,6 +174,7 @@ ISBLANK | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_BLANK ISERR | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_ERR ISERROR | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_ERROR ISEVEN | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_EVEN +ISFORMULA | \PhpOffice\PhpSpreadsheet\Calculation\Functions::ISFORMULA ISLOGICAL | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_LOGICAL ISNA | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_NA ISNONTEXT | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_NONTEXT @@ -184,13 +190,14 @@ TYPE | \PhpOffice\PhpSpreadsheet\Calculation\Functions::TYPE Excel Function | PhpSpreadsheet Function --------------------|------------------------------------------- -AND | \PhpOffice\PhpSpreadsheet\Calculation\Logical::LOGICAL_AND +AND | \PhpOffice\PhpSpreadsheet\Calculation\Logical::logicalAnd FALSE | \PhpOffice\PhpSpreadsheet\Calculation\Logical::FALSE IF | \PhpOffice\PhpSpreadsheet\Calculation\Logical::STATEMENT_IF IFERROR | \PhpOffice\PhpSpreadsheet\Calculation\Logical::IFERROR NOT | \PhpOffice\PhpSpreadsheet\Calculation\Logical::NOT -OR | \PhpOffice\PhpSpreadsheet\Calculation\Logical::LOGICAL_OR +OR | \PhpOffice\PhpSpreadsheet\Calculation\Logical::logicalOr TRUE | \PhpOffice\PhpSpreadsheet\Calculation\Logical::TRUE +XOR | \PhpOffice\PhpSpreadsheet\Calculation\Logical::logicalXor ## CATEGORY_LOOKUP_AND_REFERENCE @@ -201,8 +208,9 @@ AREAS | **Not yet Implemented** CHOOSE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::CHOOSE COLUMN | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::COLUMN COLUMNS | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::COLUMNS +FORMULATEXT | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::FORMULATEXT GETPIVOTDATA | **Not yet Implemented** -HLOOKUP | **Not yet Implemented** +HLOOKUP | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::HLOOKUP HYPERLINK | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::HYPERLINK INDEX | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::INDEX INDIRECT | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::INDIRECT @@ -222,6 +230,8 @@ Excel Function | PhpSpreadsheet Function ABS | abs ACOS | acos ACOSH | acosh +ACOT | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ACOT +ACOTH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ACOTH ASIN | asin ASINH | asinh ATAN | atan @@ -231,6 +241,10 @@ CEILING | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::CEILING COMBIN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::COMBIN COS | cos COSH | cosh +COT | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::COT +COTH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::COTH +CSC | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::CSC +CSCH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::CSCH DEGREES | rad2deg EVEN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::EVEN EXP | exp @@ -261,6 +275,8 @@ ROMAN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ROMAN ROUND | round ROUNDDOWN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ROUNDDOWN ROUNDUP | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ROUNDUP +SEC | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SEC +SECH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SECH SERIESSUM | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SERIESSUM SIGN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SIGN SIN | sin @@ -270,7 +286,7 @@ SQRTPI | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SQRTPI SUBTOTAL | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUBTOTAL SUM | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUM SUMIF | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMIF -SUMIFS | **Not yet Implemented** +SUMIFS | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMIFS SUMPRODUCT | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMPRODUCT SUMSQ | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMSQ SUMX2MY2 | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMX2MY2 @@ -336,6 +352,7 @@ MIN | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MIN MINA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINA MINIF | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINIF MODE | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MODE +MODE.SNGL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MODE NEGBINOMDIST | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::NEGBINOMDIST NORMDIST | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::NORMDIST NORMINV | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::NORMINV @@ -355,6 +372,8 @@ SLOPE | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::SLOPE SMALL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::SMALL STANDARDIZE | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STANDARDIZE STDEV | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEV +STDEV.S | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEV +STDEV.P | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVP STDEVA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVA STDEVP | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVP STDEVPA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVPA @@ -365,6 +384,8 @@ TREND | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::TREND TRIMMEAN | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::TRIMMEAN TTEST | **Not yet Implemented** VAR | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARFunc +VAR.P | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARP +VAR.S | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARFunc VARA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARA VARP | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARP VARPA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARPA @@ -380,9 +401,10 @@ BAHTTEXT | **Not yet Implemented** CHAR | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CHARACTER CLEAN | \PhpOffice\PhpSpreadsheet\Calculation\TextData::TRIMNONPRINTABLE CODE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::ASCIICODE +CONCAT | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CONCATENATE CONCATENATE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CONCATENATE DOLLAR | \PhpOffice\PhpSpreadsheet\Calculation\TextData::DOLLAR -EXACT | **Not yet Implemented** +EXACT | \PhpOffice\PhpSpreadsheet\Calculation\TextData::EXACT FIND | \PhpOffice\PhpSpreadsheet\Calculation\TextData::SEARCHSENSITIVE FINDB | \PhpOffice\PhpSpreadsheet\Calculation\TextData::SEARCHSENSITIVE FIXED | \PhpOffice\PhpSpreadsheet\Calculation\TextData::FIXEDFORMAT @@ -394,6 +416,7 @@ LENB | \PhpOffice\PhpSpreadsheet\Calculation\TextData::STRINGLENG LOWER | \PhpOffice\PhpSpreadsheet\Calculation\TextData::LOWERCASE MID | \PhpOffice\PhpSpreadsheet\Calculation\TextData::MID MIDB | \PhpOffice\PhpSpreadsheet\Calculation\TextData::MID +NUMBERVALUE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::NUMBERVALUE PHONETIC | **Not yet Implemented** PROPER | \PhpOffice\PhpSpreadsheet\Calculation\TextData::PROPERCASE REPLACE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::REPLACE @@ -406,6 +429,9 @@ SEARCHB | \PhpOffice\PhpSpreadsheet\Calculation\TextData::SEARCHINSE SUBSTITUTE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::SUBSTITUTE T | \PhpOffice\PhpSpreadsheet\Calculation\TextData::RETURNSTRING TEXT | \PhpOffice\PhpSpreadsheet\Calculation\TextData::TEXTFORMAT +TEXTJOIN | \PhpOffice\PhpSpreadsheet\Calculation\TextData::TEXTJOIN TRIM | \PhpOffice\PhpSpreadsheet\Calculation\TextData::TRIMSPACES +UNICHAR | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CHARACTER +UNICODE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::ASCIICODE UPPER | \PhpOffice\PhpSpreadsheet\Calculation\TextData::UPPERCASE -VALUE | **Not yet Implemented** +VALUE | \PhpOffice\PhpSpreadsheet\Calculation\TextData::VALUE diff --git a/docs/references/function-list-by-name.md b/docs/references/function-list-by-name.md index 8b7ad958..3602f962 100644 --- a/docs/references/function-list-by-name.md +++ b/docs/references/function-list-by-name.md @@ -9,10 +9,12 @@ ACCRINT | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet ACCRINTM | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::ACCRINTM ACOS | CATEGORY_MATH_AND_TRIG | acos ACOSH | CATEGORY_MATH_AND_TRIG | acosh +ACOT | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ACOT +ACOTH | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ACOTH ADDRESS | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::CELL_ADDRESS AMORDEGRC | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::AMORDEGRC AMORLINC | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::AMORLINC -AND | CATEGORY_LOGICAL | \PhpOffice\PhpSpreadsheet\Calculation\Logical::LOGICAL_AND +AND | CATEGORY_LOGICAL | \PhpOffice\PhpSpreadsheet\Calculation\Logical::logicalAnd AREAS | CATEGORY_LOOKUP_AND_REFERENCE | **Not yet Implemented** ASC | CATEGORY_TEXT_AND_DATA | **Not yet Implemented** ASIN | CATEGORY_MATH_AND_TRIG | asin @@ -59,12 +61,15 @@ COLUMN | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet COLUMNS | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::COLUMNS COMBIN | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::COMBIN COMPLEX | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::COMPLEX +CONCAT | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CONCATENATE CONCATENATE | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CONCATENATE CONFIDENCE | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::CONFIDENCE CONVERT | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::CONVERTUOM CORREL | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::CORREL COS | CATEGORY_MATH_AND_TRIG | cos COSH | CATEGORY_MATH_AND_TRIG | cosh +COT | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::COT +COTH | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::COTH COUNT | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNT COUNTA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTA COUNTBLANK | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTBLANK @@ -78,6 +83,8 @@ COUPNUM | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet COUPPCD | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::COUPPCD COVAR | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COVAR CRITBINOM | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::CRITBINOM +CSC | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::CSC +CSCH | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::CSCH CUBEKPIMEMBER | CATEGORY_CUBE | **Not yet Implemented** CUBEMEMBER | CATEGORY_CUBE | **Not yet Implemented** CUBEMEMBERPROPERTY | CATEGORY_CUBE | **Not yet Implemented** @@ -131,10 +138,12 @@ EDATE | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet EFFECT | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::EFFECT EOMONTH | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::EOMONTH ERF | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERF +ERF.PRECISE | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERFPRECISE ERFC | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERFC +ERFC.PRECISE | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::ERFC ERROR.TYPE | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::ERROR_TYPE EVEN | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::EVEN -EXACT | CATEGORY_TEXT_AND_DATA | **Not yet Implemented** +EXACT | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::EXACT EXP | CATEGORY_MATH_AND_TRIG | exp EXPONDIST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::EXPONDIST @@ -154,6 +163,7 @@ FISHERINV | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet FIXED | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::FIXEDFORMAT FLOOR | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::FLOOR FORECAST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::FORECAST +FORMULATEXT | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::FORMULATEXT FREQUENCY | CATEGORY_STATISTICAL | **Not yet Implemented** FTEST | CATEGORY_STATISTICAL | **Not yet Implemented** FV | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::FV @@ -180,7 +190,7 @@ HARMEAN | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet HEX2BIN | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::HEXTOBIN HEX2DEC | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::HEXTODEC HEX2OCT | CATEGORY_ENGINEERING | \PhpOffice\PhpSpreadsheet\Calculation\Engineering::HEXTOOCT -HLOOKUP | CATEGORY_LOOKUP_AND_REFERENCE | **Not yet Implemented** +HLOOKUP | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::HLOOKUP HOUR | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::HOUROFDAY HYPERLINK | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::HYPERLINK HYPGEOMDIST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::HYPGEOMDIST @@ -220,11 +230,13 @@ ISBLANK | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet ISERR | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_ERR ISERROR | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_ERROR ISEVEN | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_EVEN +ISFORMULA | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::ISFORMULA ISLOGICAL | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_LOGICAL ISNA | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_NA ISNONTEXT | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_NONTEXT ISNUMBER | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_NUMBER ISODD | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_ODD +ISOWEEKNUM | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::ISOWEEKNUM ISPMT | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::ISPMT ISREF | CATEGORY_INFORMATION | **Not yet Implemented** ISTEXT | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet\Calculation\Functions::IS_TEXT @@ -284,6 +296,7 @@ MIRR | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet MMULT | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::MMULT MOD | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::MOD MODE | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MODE +MODE.SNGL | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MODE MONTH | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::MONTHOFYEAR MROUND | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::MROUND MULTINOMIAL | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::MULTINOMIAL @@ -305,6 +318,7 @@ NOT | CATEGORY_LOGICAL | \PhpOffice\PhpSpreadsheet NOW | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::DATETIMENOW NPER | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::NPER NPV | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::NPV +NUMBERVALUE | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::NUMBERVALUE ## O @@ -319,12 +333,13 @@ ODDFYIELD | CATEGORY_FINANCIAL | **Not yet Implemented** ODDLPRICE | CATEGORY_FINANCIAL | **Not yet Implemented** ODDLYIELD | CATEGORY_FINANCIAL | **Not yet Implemented** OFFSET | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::OFFSET -OR | CATEGORY_LOGICAL | \PhpOffice\PhpSpreadsheet\Calculation\Logical::LOGICAL_OR +OR | CATEGORY_LOGICAL | \PhpOffice\PhpSpreadsheet\Calculation\Logical::logicalOr ## P Excel Function | Category | PhpSpreadsheet Function --------------------|--------------------------------|------------------------------------------- +PDURATION | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::PDURATION PEARSON | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::CORREL PERCENTILE | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::PERCENTILE PERCENTRANK | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::PERCENTRANK @@ -371,6 +386,7 @@ ROUNDDOWN | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet ROUNDUP | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::ROUNDUP ROW | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::ROW ROWS | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::ROWS +RRI | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::RRI RSQ | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::RSQ RTD | CATEGORY_LOOKUP_AND_REFERENCE | **Not yet Implemented** @@ -380,6 +396,8 @@ Excel Function | Category | PhpSpreadsheet Function --------------------|--------------------------------|------------------------------------------- SEARCH | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::SEARCHINSENSITIVE SEARCHB | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::SEARCHINSENSITIVE +SEC | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SEC +SECH | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SECH SECOND | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::SECOND SERIESSUM | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SERIESSUM SIGN | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SIGN @@ -393,6 +411,8 @@ SQRT | CATEGORY_MATH_AND_TRIG | sqrt SQRTPI | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SQRTPI STANDARDIZE | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STANDARDIZE STDEV | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEV +STDEV.S | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEV +STDEV.P | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVP STDEVA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVA STDEVP | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVP STDEVPA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::STDEVPA @@ -401,7 +421,7 @@ SUBSTITUTE | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet SUBTOTAL | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUBTOTAL SUM | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUM SUMIF | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMIF -SUMIFS | CATEGORY_MATH_AND_TRIG | **Not yet Implemented** +SUMIFS | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMIFS SUMPRODUCT | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMPRODUCT SUMSQ | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMSQ SUMX2MY2 | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::SUMX2MY2 @@ -421,6 +441,7 @@ TBILLPRICE | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet TBILLYIELD | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::TBILLYIELD TDIST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::TDIST TEXT | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::TEXTFORMAT +TEXTJOIN | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::TEXTJOIN TIME | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::TIME TIMEVALUE | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::TIMEVALUE TINV | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::TINV @@ -438,6 +459,8 @@ TYPE | CATEGORY_INFORMATION | \PhpOffice\PhpSpreadsheet Excel Function | Category | PhpSpreadsheet Function --------------------|--------------------------------|------------------------------------------- +UNICHAR | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::CHARACTER +UNICODE | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::ASCIICODE UPPER | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::UPPERCASE USDOLLAR | CATEGORY_FINANCIAL | **Not yet Implemented** @@ -445,8 +468,10 @@ USDOLLAR | CATEGORY_FINANCIAL | **Not yet Implemented** Excel Function | Category | PhpSpreadsheet Function --------------------|--------------------------------|------------------------------------------- -VALUE | CATEGORY_TEXT_AND_DATA | **Not yet Implemented** +VALUE | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::VALUE VAR | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARFunc +VAR.P | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARP +VAR.S | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARFunc VARA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARA VARP | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARP VARPA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::VARPA @@ -468,6 +493,8 @@ Excel Function | Category | PhpSpreadsheet Function --------------------|--------------------------------|------------------------------------------- XIRR | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::XIRR XNPV | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::XNPV +XOR | CATEGORY_LOGICAL | \PhpOffice\PhpSpreadsheet\Calculation\Logical::logicalXor + ## Y diff --git a/src/PhpSpreadsheet/Calculation/Calculation.php b/src/PhpSpreadsheet/Calculation/Calculation.php index 17e003e8..f5e7b4c8 100644 --- a/src/PhpSpreadsheet/Calculation/Calculation.php +++ b/src/PhpSpreadsheet/Calculation/Calculation.php @@ -224,6 +224,16 @@ class Calculation 'functionCall' => 'acosh', 'argumentCount' => '1', ], + 'ACOT' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'ACOT'], + 'argumentCount' => '1', + ], + 'ACOTH' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'ACOTH'], + 'argumentCount' => '1', + ], 'ADDRESS' => [ 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, 'functionCall' => [LookupRef::class, 'cellAddress'], @@ -425,6 +435,11 @@ class Calculation 'functionCall' => [Engineering::class, 'COMPLEX'], 'argumentCount' => '2,3', ], + 'CONCAT' => [ + 'category' => Category::CATEGORY_TEXT_AND_DATA, + 'functionCall' => [TextData::class, 'CONCATENATE'], + 'argumentCount' => '1+', + ], 'CONCATENATE' => [ 'category' => Category::CATEGORY_TEXT_AND_DATA, 'functionCall' => [TextData::class, 'CONCATENATE'], @@ -455,6 +470,16 @@ class Calculation 'functionCall' => 'cosh', 'argumentCount' => '1', ], + 'COT' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'COT'], + 'argumentCount' => '1', + ], + 'COTH' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'COTH'], + 'argumentCount' => '1', + ], 'COUNT' => [ 'category' => Category::CATEGORY_STATISTICAL, 'functionCall' => [Statistical::class, 'COUNT'], @@ -520,6 +545,16 @@ class Calculation 'functionCall' => [Statistical::class, 'CRITBINOM'], 'argumentCount' => '3', ], + 'CSC' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'CSC'], + 'argumentCount' => '1', + ], + 'CSCH' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'CSCH'], + 'argumentCount' => '1', + ], 'CUBEKPIMEMBER' => [ 'category' => Category::CATEGORY_CUBE, 'functionCall' => [Functions::class, 'DUMMY'], @@ -735,11 +770,21 @@ class Calculation 'functionCall' => [Engineering::class, 'ERF'], 'argumentCount' => '1,2', ], + 'ERF.PRECISE' => [ + 'category' => Category::CATEGORY_ENGINEERING, + 'functionCall' => [Engineering::class, 'ERFPRECISE'], + 'argumentCount' => '1', + ], 'ERFC' => [ 'category' => Category::CATEGORY_ENGINEERING, 'functionCall' => [Engineering::class, 'ERFC'], 'argumentCount' => '1', ], + 'ERFC.PRECISE' => [ + 'category' => Category::CATEGORY_ENGINEERING, + 'functionCall' => [Engineering::class, 'ERFC'], + 'argumentCount' => '1', + ], 'ERROR.TYPE' => [ 'category' => Category::CATEGORY_INFORMATION, 'functionCall' => [Functions::class, 'errorType'], @@ -825,6 +870,13 @@ class Calculation 'functionCall' => [Statistical::class, 'FORECAST'], 'argumentCount' => '3', ], + 'FORMULATEXT' => [ + 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, + 'functionCall' => [LookupRef::class, 'FORMULATEXT'], + 'argumentCount' => '1', + 'passCellReference' => true, + 'passByReference' => [true], + ], 'FREQUENCY' => [ 'category' => Category::CATEGORY_STATISTICAL, 'functionCall' => [Functions::class, 'DUMMY'], @@ -1114,6 +1166,11 @@ class Calculation 'functionCall' => [Functions::class, 'isOdd'], 'argumentCount' => '1', ], + 'ISOWEEKNUM' => [ + 'category' => Category::CATEGORY_DATE_AND_TIME, + 'functionCall' => [DateTime::class, 'ISOWEEKNUM'], + 'argumentCount' => '1', + ], 'ISPMT' => [ 'category' => Category::CATEGORY_FINANCIAL, 'functionCall' => [Financial::class, 'ISPMT'], @@ -1394,6 +1451,11 @@ class Calculation 'functionCall' => [Financial::class, 'NPV'], 'argumentCount' => '2+', ], + 'NUMBERVALUE' => [ + 'category' => Category::CATEGORY_TEXT_AND_DATA, + 'functionCall' => [TextData::class, 'NUMBERVALUE'], + 'argumentCount' => '1+', + ], 'OCT2BIN' => [ 'category' => Category::CATEGORY_ENGINEERING, 'functionCall' => [Engineering::class, 'OCTTOBIN'], @@ -1446,6 +1508,11 @@ class Calculation 'functionCall' => [Logical::class, 'logicalOr'], 'argumentCount' => '1+', ], + 'PDURATION' => [ + 'category' => Category::CATEGORY_FINANCIAL, + 'functionCall' => [Financial::class, 'PDURATION'], + 'argumentCount' => '3', + ], 'PEARSON' => [ 'category' => Category::CATEGORY_STATISTICAL, 'functionCall' => [Statistical::class, 'CORREL'], @@ -1627,6 +1694,11 @@ class Calculation 'functionCall' => [LookupRef::class, 'ROWS'], 'argumentCount' => '1', ], + 'RRI' => [ + 'category' => Category::CATEGORY_FINANCIAL, + 'functionCall' => [Financial::class, 'RRI'], + 'argumentCount' => '3', + ], 'RSQ' => [ 'category' => Category::CATEGORY_STATISTICAL, 'functionCall' => [Statistical::class, 'RSQ'], @@ -1647,6 +1719,16 @@ class Calculation 'functionCall' => [TextData::class, 'SEARCHINSENSITIVE'], 'argumentCount' => '2,3', ], + 'SEC' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'SEC'], + 'argumentCount' => '1', + ], + 'SECH' => [ + 'category' => Category::CATEGORY_MATH_AND_TRIG, + 'functionCall' => [MathTrig::class, 'SECH'], + 'argumentCount' => '1', + ], 'SECOND' => [ 'category' => Category::CATEGORY_DATE_AND_TIME, 'functionCall' => [DateTime::class, 'SECOND'], @@ -1838,6 +1920,11 @@ class Calculation 'functionCall' => [TextData::class, 'TEXTFORMAT'], 'argumentCount' => '2', ], + 'TEXTJOIN' => [ + 'category' => Category::CATEGORY_TEXT_AND_DATA, + 'functionCall' => [TextData::class, 'TEXTJOIN'], + 'argumentCount' => '3+', + ], 'TIME' => [ 'category' => Category::CATEGORY_DATE_AND_TIME, 'functionCall' => [DateTime::class, 'TIME'], @@ -1898,6 +1985,16 @@ class Calculation 'functionCall' => [Functions::class, 'TYPE'], 'argumentCount' => '1', ], + 'UNICHAR' => [ + 'category' => Category::CATEGORY_TEXT_AND_DATA, + 'functionCall' => [TextData::class, 'CHARACTER'], + 'argumentCount' => '1', + ], + 'UNICODE' => [ + 'category' => Category::CATEGORY_TEXT_AND_DATA, + 'functionCall' => [TextData::class, 'ASCIICODE'], + 'argumentCount' => '1', + ], 'UPPER' => [ 'category' => Category::CATEGORY_TEXT_AND_DATA, 'functionCall' => [TextData::class, 'UPPERCASE'], @@ -1918,6 +2015,16 @@ class Calculation 'functionCall' => [Statistical::class, 'VARFunc'], 'argumentCount' => '1+', ], + 'VAR.P' => [ + 'category' => Category::CATEGORY_STATISTICAL, + 'functionCall' => [Statistical::class, 'VARP'], + 'argumentCount' => '1+', + ], + 'VAR.S' => [ + 'category' => Category::CATEGORY_STATISTICAL, + 'functionCall' => [Statistical::class, 'VARFunc'], + 'argumentCount' => '1+', + ], 'VARA' => [ 'category' => Category::CATEGORY_STATISTICAL, 'functionCall' => [Statistical::class, 'VARA'], @@ -1973,6 +2080,11 @@ class Calculation 'functionCall' => [Financial::class, 'XNPV'], 'argumentCount' => '3', ], + 'XOR' => [ + 'category' => Category::CATEGORY_LOGICAL, + 'functionCall' => [Logical::class, 'logicalXor'], + 'argumentCount' => '1+', + ], 'YEAR' => [ 'category' => Category::CATEGORY_DATE_AND_TIME, 'functionCall' => [DateTime::class, 'YEAR'], diff --git a/src/PhpSpreadsheet/Calculation/DateTime.php b/src/PhpSpreadsheet/Calculation/DateTime.php index 0bd131c0..a07a28d1 100644 --- a/src/PhpSpreadsheet/Calculation/DateTime.php +++ b/src/PhpSpreadsheet/Calculation/DateTime.php @@ -10,7 +10,7 @@ class DateTime /** * Identify if a year is a leap year or not. * - * @param int $year The year to test + * @param int|string $year The year to test * * @return bool TRUE if the year is a leap year, otherwise FALSE */ @@ -70,7 +70,7 @@ class DateTime (Functions::getCompatibilityMode() == Functions::COMPATIBILITY_GNUMERIC)) { return Functions::VALUE(); } - if ((is_object($dateValue)) && ($dateValue instanceof \DateTime)) { + if ((is_object($dateValue)) && ($dateValue instanceof \DateTimeImmutable)) { $dateValue = Date::PHPToExcel($dateValue); } else { $saveReturnDateType = Functions::getReturnDateType(); @@ -650,7 +650,7 @@ class DateTime * or a standard date string * @param string $unit * - * @return int Interval between the dates + * @return int|string Interval between the dates */ public static function DATEDIF($startDate = 0, $endDate = 0, $unit = 'D') { @@ -792,7 +792,7 @@ class DateTime * occur on the 31st of a month become equal to the 30th of the * same month. * - * @return int Number of days between start date and end date + * @return int|string Number of days between start date and end date */ public static function DAYS360($startDate = 0, $endDate = 0, $method = false) { @@ -942,7 +942,7 @@ class DateTime * @param mixed $endDate Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard date string * - * @return int Interval between the dates + * @return int|string Interval between the dates */ public static function NETWORKDAYS($startDate, $endDate, ...$dateArgs) { @@ -1127,7 +1127,7 @@ class DateTime * @param mixed $dateValue Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard date string * - * @return int Day of the month + * @return int|string Day of the month */ public static function DAYOFMONTH($dateValue = 1) { @@ -1169,7 +1169,7 @@ class DateTime * 2 Numbers 1 (Monday) through 7 (Sunday). * 3 Numbers 0 (Monday) through 6 (Sunday). * - * @return int Day of the week value + * @return int|string Day of the week value */ public static function WEEKDAY($dateValue = 1, $style = 1) { @@ -1248,7 +1248,7 @@ class DateTime * 1 or omitted Week begins on Sunday. * 2 Week begins on Monday. * - * @return int Week Number + * @return int|string Week Number */ public static function WEEKNUM($dateValue = 1, $method = 1) { @@ -1286,6 +1286,37 @@ class DateTime return (int) $weekOfYear; } + /** + * ISOWEEKNUM. + * + * Returns the ISO 8601 week number of the year for a specified date. + * + * Excel Function: + * ISOWEEKNUM(dateValue) + * + * @param mixed $dateValue Excel date serial value (float), PHP date timestamp (integer), + * PHP DateTime object, or a standard date string + * + * @return int|string Week Number + */ + public static function ISOWEEKNUM($dateValue = 1) + { + $dateValue = Functions::flattenSingleValue($dateValue); + + if ($dateValue === null) { + $dateValue = 1; + } elseif (is_string($dateValue = self::getDateValue($dateValue))) { + return Functions::VALUE(); + } elseif ($dateValue < 0.0) { + return Functions::NAN(); + } + + // Execute function + $PHPDateObject = Date::excelToDateTimeObject($dateValue); + + return (int) $PHPDateObject->format('W'); + } + /** * MONTHOFYEAR. * @@ -1298,7 +1329,7 @@ class DateTime * @param mixed $dateValue Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard date string * - * @return int Month of the year + * @return int|string Month of the year */ public static function MONTHOFYEAR($dateValue = 1) { @@ -1331,7 +1362,7 @@ class DateTime * @param mixed $dateValue Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard date string * - * @return int Year + * @return int|string Year */ public static function YEAR($dateValue = 1) { @@ -1363,7 +1394,7 @@ class DateTime * @param mixed $timeValue Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard time string * - * @return int Hour + * @return int|string Hour */ public static function HOUROFDAY($timeValue = 0) { @@ -1404,7 +1435,7 @@ class DateTime * @param mixed $timeValue Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard time string * - * @return int Minute + * @return int|string Minute */ public static function MINUTE($timeValue = 0) { @@ -1445,7 +1476,7 @@ class DateTime * @param mixed $timeValue Excel date serial value (float), PHP date timestamp (integer), * PHP DateTime object, or a standard time string * - * @return int Second + * @return int|string Second */ public static function SECOND($timeValue = 0) { diff --git a/src/PhpSpreadsheet/Calculation/Engineering.php b/src/PhpSpreadsheet/Calculation/Engineering.php index 2be5c50f..e16464b9 100644 --- a/src/PhpSpreadsheet/Calculation/Engineering.php +++ b/src/PhpSpreadsheet/Calculation/Engineering.php @@ -2431,7 +2431,7 @@ class Engineering * Note: In Excel 2007 or earlier, if you input a negative value for the upper or lower bound arguments, * the function would return a #NUM! error. However, in Excel 2010, the function algorithm was * improved, so that it can now calculate the function for both positive and negative ranges. - * PhpSpreadsheet follows Excel 2010 behaviour, and accepts nagative arguments. + * PhpSpreadsheet follows Excel 2010 behaviour, and accepts negative arguments. * * Excel Function: * ERF(lower[,upper]) @@ -2440,7 +2440,7 @@ class Engineering * @param float $upper upper bound for integrating ERF. * If omitted, ERF integrates between zero and lower_limit * - * @return float + * @return float|string */ public static function ERF($lower, $upper = null) { @@ -2459,6 +2459,25 @@ class Engineering return Functions::VALUE(); } + /** + * ERFPRECISE. + * + * Returns the error function integrated between the lower and upper bound arguments. + * + * Excel Function: + * ERF.PRECISE(limit) + * + * @param float $limit bound for integrating ERF + * + * @return float|string + */ + public static function ERFPRECISE($limit) + { + $limit = Functions::flattenSingleValue($limit); + + return self::ERF($limit); + } + // // Private method to calculate the erfc value // @@ -2507,7 +2526,7 @@ class Engineering * * @param float $x The lower bound for integrating ERFC * - * @return float + * @return float|string */ public static function ERFC($x) { diff --git a/src/PhpSpreadsheet/Calculation/Financial.php b/src/PhpSpreadsheet/Calculation/Financial.php index 24cdfb0b..3cb6d40a 100644 --- a/src/PhpSpreadsheet/Calculation/Financial.php +++ b/src/PhpSpreadsheet/Calculation/Financial.php @@ -6,7 +6,7 @@ use PhpOffice\PhpSpreadsheet\Shared\Date; class Financial { - const FINANCIAL_MAX_ITERATIONS = 128; + const FINANCIAL_MAX_ITERATIONS = 32; const FINANCIAL_PRECISION = 1.0e-08; @@ -63,8 +63,8 @@ class Financial * * Returns the number of days in a specified year, as defined by the "basis" value * - * @param int $year The year against which we're testing - * @param int $basis The type of day count: + * @param int|string $year The year against which we're testing + * @param int|string $basis The type of day count: * 0 or omitted US (NASD) 360 * 1 Actual (365 or 366 in a leap year) * 2 360 @@ -144,7 +144,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function ACCRINT($issue, $firstinterest, $settlement, $rate, $par = 1000, $frequency = 1, $basis = 0) { @@ -197,7 +197,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function ACCRINTM($issue, $settlement, $rate, $par = 1000, $basis = 0) { @@ -401,7 +401,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function COUPDAYBS($settlement, $maturity, $frequency, $basis = 0) { @@ -460,7 +460,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function COUPDAYS($settlement, $maturity, $frequency, $basis = 0) { @@ -489,7 +489,7 @@ class Financial case 1: // Actual/actual if ($frequency == 1) { - $daysPerYear = self::daysPerYear(DateTime::YEAR($maturity), $basis); + $daysPerYear = self::daysPerYear(DateTime::YEAR($settlement), $basis); return $daysPerYear / $frequency; } @@ -534,7 +534,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function COUPDAYSNC($settlement, $maturity, $frequency, $basis = 0) { @@ -651,7 +651,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return int + * @return int|string */ public static function COUPNUM($settlement, $maturity, $frequency, $basis = 0) { @@ -769,7 +769,7 @@ class Financial * 0 or omitted At the end of the period. * 1 At the beginning of the period. * - * @return float + * @return float|string */ public static function CUMIPMT($rate, $nper, $pv, $start, $end, $type = 0) { @@ -817,7 +817,7 @@ class Financial * 0 or omitted At the end of the period. * 1 At the beginning of the period. * - * @return float + * @return float|string */ public static function CUMPRINC($rate, $nper, $pv, $start, $end, $type = 0) { @@ -870,7 +870,7 @@ class Financial * @param int $month Number of months in the first year. If month is omitted, * it defaults to 12. * - * @return float + * @return float|string */ public static function DB($cost, $salvage, $life, $period, $month = 12) { @@ -940,7 +940,7 @@ class Financial * If factor is omitted, it is assumed to be 2 (the * double-declining balance method). * - * @return float + * @return float|string */ public static function DDB($cost, $salvage, $life, $period, $factor = 2.0) { @@ -1004,7 +1004,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function DISC($settlement, $maturity, $price, $redemption, $basis = 0) { @@ -1049,7 +1049,7 @@ class Financial * @param float $fractional_dollar Fractional Dollar * @param int $fraction Fraction * - * @return float + * @return float|string */ public static function DOLLARDE($fractional_dollar = null, $fraction = 0) { @@ -1087,7 +1087,7 @@ class Financial * @param float $decimal_dollar Decimal Dollar * @param int $fraction Fraction * - * @return float + * @return float|string */ public static function DOLLARFR($decimal_dollar = null, $fraction = 0) { @@ -1124,7 +1124,7 @@ class Financial * @param float $nominal_rate Nominal interest rate * @param int $npery Number of compounding payments per year * - * @return float + * @return float|string */ public static function EFFECT($nominal_rate = 0, $npery = 0) { @@ -1160,7 +1160,7 @@ class Financial * 0 or omitted At the end of the period. * 1 At the beginning of the period. * - * @return float + * @return float|string */ public static function FV($rate = 0, $nper = 0, $pmt = 0, $pv = 0, $type = 0) { @@ -1230,7 +1230,7 @@ class Financial * 3 Actual/365 * 4 European 30/360 * - * @return float + * @return float|string */ public static function INTRATE($settlement, $maturity, $investment, $redemption, $basis = 0) { @@ -1275,7 +1275,7 @@ class Financial * @param float $fv Future Value * @param int $type Payment type: 0 = at the end of each period, 1 = at the beginning of each period * - * @return float + * @return float|string */ public static function IPMT($rate, $per, $nper, $pv, $fv = 0, $type = 0) { @@ -1318,7 +1318,7 @@ class Financial * calculate the internal rate of return. * @param float $guess A number that you guess is close to the result of IRR * - * @return float + * @return float|string */ public static function IRR($values, $guess = 0.1) { @@ -1428,7 +1428,7 @@ class Financial * @param float $finance_rate The interest rate you pay on the money used in the cash flows * @param float $reinvestment_rate The interest rate you receive on the cash flows as you reinvest them * - * @return float + * @return float|string */ public static function MIRR($values, $finance_rate, $reinvestment_rate) { @@ -1470,7 +1470,7 @@ class Financial * @param float $effect_rate Effective interest rate * @param int $npery Number of compounding payments per year * - * @return float + * @return float|string */ public static function NOMINAL($effect_rate = 0, $npery = 0) { @@ -1497,7 +1497,7 @@ class Financial * @param float $fv Future Value * @param int $type Payment type: 0 = at the end of each period, 1 = at the beginning of each period * - * @return float + * @return float|string */ public static function NPER($rate = 0, $pmt = 0, $pv = 0, $fv = 0, $type = 0) { @@ -1556,6 +1556,33 @@ class Financial return $returnValue; } + /** + * PDURATION. + * + * Calculates the number of periods required for an investment to reach a specified value. + * + * @param float $rate Interest rate per period + * @param float $pv Present Value + * @param float $fv Future Value + * + * @return float|string + */ + public static function PDURATION($rate = 0, $pv = 0, $fv = 0) + { + $rate = Functions::flattenSingleValue($rate); + $pv = Functions::flattenSingleValue($pv); + $fv = Functions::flattenSingleValue($fv); + + // Validate parameters + if (!is_numeric($rate) || !is_numeric($pv) || !is_numeric($fv)) { + return Functions::VALUE(); + } elseif ($rate <= 0.0 || $pv <= 0.0 || $fv <= 0.0) { + return Functions::NAN(); + } + + return (log($fv) - log($pv)) / log(1 + $rate); + } + /** * PMT. * @@ -1933,6 +1960,33 @@ class Financial return Functions::VALUE(); } + /** + * RRI. + * + * Calculates the interest rate required for an investment to grow to a specified future value . + * + * @param float $nper The number of periods over which the investment is made + * @param float $pv Present Value + * @param float $fv Future Value + * + * @return float|string + */ + public static function RRI($nper = 0, $pv = 0, $fv = 0) + { + $nper = Functions::flattenSingleValue($nper); + $pv = Functions::flattenSingleValue($pv); + $fv = Functions::flattenSingleValue($fv); + + // Validate parameters + if (!is_numeric($nper) || !is_numeric($pv) || !is_numeric($fv)) { + return Functions::VALUE(); + } elseif ($nper <= 0.0 || $pv <= 0.0 || $fv < 0.0) { + return Functions::NAN(); + } + + return pow($fv / $pv, 1 / $nper) - 1; + } + /** * SLN. * @@ -1942,7 +1996,7 @@ class Financial * @param mixed $salvage Value at the end of the depreciation * @param mixed $life Number of periods over which the asset is depreciated * - * @return float + * @return float|string */ public static function SLN($cost, $salvage, $life) { @@ -1972,7 +2026,7 @@ class Financial * @param mixed $life Number of periods over which the asset is depreciated * @param mixed $period Period * - * @return float + * @return float|string */ public static function SYD($cost, $salvage, $life, $period) { diff --git a/src/PhpSpreadsheet/Calculation/Functions.php b/src/PhpSpreadsheet/Calculation/Functions.php index b06cc4a7..6fa07de9 100644 --- a/src/PhpSpreadsheet/Calculation/Functions.php +++ b/src/PhpSpreadsheet/Calculation/Functions.php @@ -648,17 +648,26 @@ class Functions /** * ISFORMULA. * - * @param mixed $value The cell to check + * @param mixed $cellReference The cell to check * @param Cell $pCell The current cell (containing this formula) * * @return bool|string */ - public static function isFormula($value = '', Cell $pCell = null) + public static function isFormula($cellReference = '', Cell $pCell = null) { if ($pCell === null) { return self::REF(); } - return substr($pCell->getWorksheet()->getCell($value)->getValue(), 0, 1) === '='; + preg_match('/^' . Calculation::CALCULATION_REGEXP_CELLREF . '$/i', $cellReference, $matches); + + $cellReference = $matches[6] . $matches[7]; + $worksheetName = trim($matches[3], "'"); + + $worksheet = (!empty($worksheetName)) + ? $pCell->getWorksheet()->getParent()->getSheetByName($worksheetName) + : $pCell->getWorksheet(); + + return $worksheet->getCell($cellReference)->isFormula(); } } diff --git a/src/PhpSpreadsheet/Calculation/Logical.php b/src/PhpSpreadsheet/Calculation/Logical.php index 6b126927..c36e3fca 100644 --- a/src/PhpSpreadsheet/Calculation/Logical.php +++ b/src/PhpSpreadsheet/Calculation/Logical.php @@ -38,6 +38,32 @@ class Logical return false; } + private static function countTrueValues(array $args) + { + $returnValue = 0; + + foreach ($args as $arg) { + // Is it a boolean value? + if (is_bool($arg)) { + $returnValue += $arg; + } elseif ((is_numeric($arg)) && (!is_string($arg))) { + $returnValue += ((int) $arg != 0); + } elseif (is_string($arg)) { + $arg = strtoupper($arg); + if (($arg == 'TRUE') || ($arg == Calculation::getTRUE())) { + $arg = true; + } elseif (($arg == 'FALSE') || ($arg == Calculation::getFALSE())) { + $arg = false; + } else { + return Functions::VALUE(); + } + $returnValue += ($arg != 0); + } + } + + return $returnValue; + } + /** * LOGICAL_AND. * @@ -62,37 +88,23 @@ class Logical */ public static function logicalAnd(...$args) { - // Return value - $returnValue = true; + $args = Functions::flattenArray($args); - // Loop through the arguments - $aArgs = Functions::flattenArray($args); - $argCount = -1; - foreach ($aArgs as $argCount => $arg) { - // Is it a boolean value? - if (is_bool($arg)) { - $returnValue = $returnValue && $arg; - } elseif ((is_numeric($arg)) && (!is_string($arg))) { - $returnValue = $returnValue && ($arg != 0); - } elseif (is_string($arg)) { - $arg = strtoupper($arg); - if (($arg == 'TRUE') || ($arg == Calculation::getTRUE())) { - $arg = true; - } elseif (($arg == 'FALSE') || ($arg == Calculation::getFALSE())) { - $arg = false; - } else { - return Functions::VALUE(); - } - $returnValue = $returnValue && ($arg != 0); - } - } - - // Return - if ($argCount < 0) { + if (count($args) == 0) { return Functions::VALUE(); } - return $returnValue; + $args = array_filter($args, function ($value) { + return $value !== null || (is_string($value) && trim($value) == ''); + }); + $argCount = count($args); + + $returnValue = self::countTrueValues($args); + if (is_string($returnValue)) { + return $returnValue; + } + + return ($returnValue > 0) && ($returnValue == $argCount); } /** @@ -119,37 +131,65 @@ class Logical */ public static function logicalOr(...$args) { - // Return value - $returnValue = false; + $args = Functions::flattenArray($args); - // Loop through the arguments - $aArgs = Functions::flattenArray($args); - $argCount = -1; - foreach ($aArgs as $argCount => $arg) { - // Is it a boolean value? - if (is_bool($arg)) { - $returnValue = $returnValue || $arg; - } elseif ((is_numeric($arg)) && (!is_string($arg))) { - $returnValue = $returnValue || ($arg != 0); - } elseif (is_string($arg)) { - $arg = strtoupper($arg); - if (($arg == 'TRUE') || ($arg == Calculation::getTRUE())) { - $arg = true; - } elseif (($arg == 'FALSE') || ($arg == Calculation::getFALSE())) { - $arg = false; - } else { - return Functions::VALUE(); - } - $returnValue = $returnValue || ($arg != 0); - } - } - - // Return - if ($argCount < 0) { + if (count($args) == 0) { return Functions::VALUE(); } - return $returnValue; + $args = array_filter($args, function ($value) { + return $value !== null || (is_string($value) && trim($value) == ''); + }); + + $returnValue = self::countTrueValues($args); + if (is_string($returnValue)) { + return $returnValue; + } + + return $returnValue > 0; + } + + /** + * LOGICAL_XOR. + * + * Returns the Exclusive Or logical operation for one or more supplied conditions. + * i.e. the Xor function returns TRUE if an odd number of the supplied conditions evaluate to TRUE, and FALSE otherwise. + * + * Excel Function: + * =XOR(logical1[,logical2[, ...]]) + * + * The arguments must evaluate to logical values such as TRUE or FALSE, or the arguments must be arrays + * or references that contain logical values. + * + * Boolean arguments are treated as True or False as appropriate + * Integer or floating point arguments are treated as True, except for 0 or 0.0 which are False + * If any argument value is a string, or a Null, the function returns a #VALUE! error, unless the string holds + * the value TRUE or FALSE, in which case it is evaluated as the corresponding boolean value + * + * @category Logical Functions + * + * @param mixed $args Data values + * + * @return bool|string the logical XOR of the arguments + */ + public static function logicalXor(...$args) + { + $args = Functions::flattenArray($args); + + if (count($args) == 0) { + return Functions::VALUE(); + } + + $args = array_filter($args, function ($value) { + return $value !== null || (is_string($value) && trim($value) == ''); + }); + + $returnValue = self::countTrueValues($args); + if (is_string($returnValue)) { + return $returnValue; + } + + return $returnValue % 2 == 1; } /** @@ -176,6 +216,7 @@ class Logical public static function NOT($logical = false) { $logical = Functions::flattenSingleValue($logical); + if (is_string($logical)) { $logical = strtoupper($logical); if (($logical == 'TRUE') || ($logical == Calculation::getTRUE())) { diff --git a/src/PhpSpreadsheet/Calculation/LookupRef.php b/src/PhpSpreadsheet/Calculation/LookupRef.php index d8cdc242..71550a7b 100644 --- a/src/PhpSpreadsheet/Calculation/LookupRef.php +++ b/src/PhpSpreadsheet/Calculation/LookupRef.php @@ -866,4 +866,33 @@ class LookupRef return self::VLOOKUP($lookup_value, $lookup_vector, 2); } + + /** + * FORMULATEXT. + * + * @param mixed $cellReference The cell to check + * @param Cell $pCell The current cell (containing this formula) + * + * @return string + */ + public static function FORMULATEXT($cellReference = '', Cell $pCell = null) + { + if ($pCell === null) { + return Functions::REF(); + } + + preg_match('/^' . Calculation::CALCULATION_REGEXP_CELLREF . '$/i', $cellReference, $matches); + + $cellReference = $matches[6] . $matches[7]; + $worksheetName = trim($matches[3], "'"); + $worksheet = (!empty($worksheetName)) + ? $pCell->getWorksheet()->getParent()->getSheetByName($worksheetName) + : $pCell->getWorksheet(); + + if (!$worksheet->getCell($cellReference)->isFormula()) { + return Functions::NA(); + } + + return $worksheet->getCell($cellReference)->getValue(); + } } diff --git a/src/PhpSpreadsheet/Calculation/MathTrig.php b/src/PhpSpreadsheet/Calculation/MathTrig.php index 68aaf7b6..41fc0de2 100644 --- a/src/PhpSpreadsheet/Calculation/MathTrig.php +++ b/src/PhpSpreadsheet/Calculation/MathTrig.php @@ -1088,9 +1088,9 @@ class MathTrig function ($index) use ($cellReference) { list(, $row, $column) = explode('.', $index); if ($cellReference->getWorksheet()->cellExists($column . $row)) { - //take this cell out if it contains the SUBTOTAL formula + //take this cell out if it contains the SUBTOTAL or AGGREGATE functions in a formula $isFormula = $cellReference->getWorksheet()->getCell($column . $row)->isFormula(); - $cellFormula = !preg_match('/^=.*\bSUBTOTAL\s*\(/i', $cellReference->getWorksheet()->getCell($column . $row)->getValue()); + $cellFormula = !preg_match('/^=.*\b(SUBTOTAL|AGGREGATE)\s*\(/i', $cellReference->getWorksheet()->getCell($column . $row)->getValue()); return !$isFormula || $cellFormula; } @@ -1458,4 +1458,178 @@ class MathTrig return ((int) ($value * $adjust)) / $adjust; } + + /** + * SEC. + * + * Returns the secant of an angle. + * + * @param float $angle Number + * + * @return float|string The secant of the angle + */ + public static function SEC($angle) + { + $angle = Functions::flattenSingleValue($angle); + + if (!is_numeric($angle)) { + return Functions::VALUE(); + } + + $result = cos($angle); + + return ($result == 0.0) ? Functions::DIV0() : 1 / $result; + } + + /** + * SECH. + * + * Returns the hyperbolic secant of an angle. + * + * @param float $angle Number + * + * @return float|string The hyperbolic secant of the angle + */ + public static function SECH($angle) + { + $angle = Functions::flattenSingleValue($angle); + + if (!is_numeric($angle)) { + return Functions::VALUE(); + } + + $result = cosh($angle); + + return ($result == 0.0) ? Functions::DIV0() : 1 / $result; + } + + /** + * CSC. + * + * Returns the cosecant of an angle. + * + * @param float $angle Number + * + * @return float|string The cosecant of the angle + */ + public static function CSC($angle) + { + $angle = Functions::flattenSingleValue($angle); + + if (!is_numeric($angle)) { + return Functions::VALUE(); + } + + $result = sin($angle); + + return ($result == 0.0) ? Functions::DIV0() : 1 / $result; + } + + /** + * CSCH. + * + * Returns the hyperbolic cosecant of an angle. + * + * @param float $angle Number + * + * @return float|string The hyperbolic cosecant of the angle + */ + public static function CSCH($angle) + { + $angle = Functions::flattenSingleValue($angle); + + if (!is_numeric($angle)) { + return Functions::VALUE(); + } + + $result = sinh($angle); + + return ($result == 0.0) ? Functions::DIV0() : 1 / $result; + } + + /** + * COT. + * + * Returns the cotangent of an angle. + * + * @param float $angle Number + * + * @return float|string The cotangent of the angle + */ + public static function COT($angle) + { + $angle = Functions::flattenSingleValue($angle); + + if (!is_numeric($angle)) { + return Functions::VALUE(); + } + + $result = tan($angle); + + return ($result == 0.0) ? Functions::DIV0() : 1 / $result; + } + + /** + * COTH. + * + * Returns the hyperbolic cotangent of an angle. + * + * @param float $angle Number + * + * @return float|string The hyperbolic cotangent of the angle + */ + public static function COTH($angle) + { + $angle = Functions::flattenSingleValue($angle); + + if (!is_numeric($angle)) { + return Functions::VALUE(); + } + + $result = tanh($angle); + + return ($result == 0.0) ? Functions::DIV0() : 1 / $result; + } + + /** + * ACOT. + * + * Returns the arccotangent of a number. + * + * @param float $number Number + * + * @return float|string The arccotangent of the number + */ + public static function ACOT($number) + { + $number = Functions::flattenSingleValue($number); + + if (!is_numeric($number)) { + return Functions::VALUE(); + } + + return (M_PI / 2) - atan($number); + } + + /** + * ACOTH. + * + * Returns the hyperbolic arccotangent of a number. + * + * @param float $number Number + * + * @return float|string The hyperbolic arccotangent of the number + */ + public static function ACOTH($number) + { + $number = Functions::flattenSingleValue($number); + + if (!is_numeric($number)) { + return Functions::VALUE(); + } + + $result = log(($number + 1) / ($number - 1)) / 2; + + return is_nan($result) ? Functions::NAN() : $result; + } } diff --git a/src/PhpSpreadsheet/Calculation/TextData.php b/src/PhpSpreadsheet/Calculation/TextData.php index 05553fbe..e30b2ff7 100644 --- a/src/PhpSpreadsheet/Calculation/TextData.php +++ b/src/PhpSpreadsheet/Calculation/TextData.php @@ -578,6 +578,52 @@ class TextData return (float) $value; } + /** + * NUMBERVALUE. + * + * @param mixed $value Value to check + * @param string $decimalSeparator decimal separator, defaults to locale defined value + * @param string $groupSeparator group/thosands separator, defaults to locale defined value + * + * @return float|string + */ + public static function NUMBERVALUE($value = '', $decimalSeparator = null, $groupSeparator = null) + { + $value = Functions::flattenSingleValue($value); + $decimalSeparator = Functions::flattenSingleValue($decimalSeparator); + $groupSeparator = Functions::flattenSingleValue($groupSeparator); + + if (!is_numeric($value)) { + $decimalSeparator = empty($decimalSeparator) ? StringHelper::getDecimalSeparator() : $decimalSeparator; + $groupSeparator = empty($groupSeparator) ? StringHelper::getThousandsSeparator() : $groupSeparator; + + $decimalPositions = preg_match_all('/' . preg_quote($decimalSeparator) . '/', $value, $matches, PREG_OFFSET_CAPTURE); + if ($decimalPositions > 1) { + return Functions::VALUE(); + } + $decimalOffset = array_pop($matches[0])[1]; + if (strpos($value, $groupSeparator, $decimalOffset) !== false) { + return Functions::VALUE(); + } + + $value = str_replace([$groupSeparator, $decimalSeparator], ['', '.'], $value); + + // Handle the special case of trailing % signs + $percentageString = rtrim($value, '%'); + if (!is_numeric($percentageString)) { + return Functions::VALUE(); + } + + $percentageAdjustment = strlen($value) - strlen($percentageString); + if ($percentageAdjustment) { + $value = (float) $percentageString; + $value /= pow(10, $percentageAdjustment * 2); + } + } + + return (float) $value; + } + /** * Compares two text strings and returns TRUE if they are exactly the same, FALSE otherwise. * EXACT is case-sensitive but ignores formatting differences. @@ -595,4 +641,32 @@ class TextData return (string) $value2 === (string) $value1; } + + /** + * TEXTJOIN. + * + * @param mixed $delimiter + * @param mixed $ignoreEmpty + * @param mixed $args + * + * @return string + */ + public static function TEXTJOIN($delimiter, $ignoreEmpty, ...$args) + { + // Loop through arguments + $aArgs = Functions::flattenArray($args); + foreach ($aArgs as $key => &$arg) { + if ($ignoreEmpty && trim($arg) == '') { + unset($aArgs[$key]); + } elseif (is_bool($arg)) { + if (Functions::getCompatibilityMode() == Functions::COMPATIBILITY_OPENOFFICE) { + $arg = (int) $arg; + } else { + $arg = ($arg) ? Calculation::getTRUE() : Calculation::getFALSE(); + } + } + } + + return implode($delimiter, $aArgs); + } } diff --git a/src/PhpSpreadsheet/Calculation/functionlist.txt b/src/PhpSpreadsheet/Calculation/functionlist.txt index 5ac6cf41..c8dcfd50 100644 --- a/src/PhpSpreadsheet/Calculation/functionlist.txt +++ b/src/PhpSpreadsheet/Calculation/functionlist.txt @@ -3,6 +3,8 @@ ACCRINT ACCRINTM ACOS ACOSH +ACOT +ACOTH ADDRESS AMORDEGRC AMORLINC @@ -43,12 +45,15 @@ COLUMN COLUMNS COMBIN COMPLEX +CONCAT CONCATENATE CONFIDENCE CONVERT CORREL COS COSH +COT +COTH COUNT COUNTA COUNTBLANK @@ -62,6 +67,8 @@ COUPNUM COUPPCD COVAR CRITBINOM +CSC +CSCH CUBEKPIMEMBER CUBEMEMBER CUBEMEMBERPROPERTY @@ -105,7 +112,9 @@ EDATE EFFECT EOMONTH ERF +ERF.PRECISE ERFC +ERFC.PRECISE ERROR.TYPE EVEN EXACT @@ -177,6 +186,7 @@ ISNA ISNONTEXT ISNUMBER ISODD +ISOWEEKNUM ISPMT ISREF ISTEXT @@ -229,6 +239,7 @@ NOT NOW NPER NPV +NUMBERVALUE OCT2BIN OCT2DEC OCT2HEX @@ -239,6 +250,7 @@ ODDLPRICE ODDLYIELD OFFSET OR +PDURATION PEARSON PERCENTILE PERCENTRANK @@ -275,10 +287,13 @@ ROUNDDOWN ROUNDUP ROW ROWS +RRI RSQ RTD SEARCH SEARCHB +SEC +SECH SECOND SERIESSUM SIGN @@ -292,6 +307,8 @@ SQRT SQRTPI STANDARDIZE STDEV +STDEV.A +STDEV.P STDEVA STDEVP STDEVPA @@ -315,6 +332,7 @@ TBILLPRICE TBILLYIELD TDIST TEXT +TEXTJOIN TIME TIMEVALUE TINV @@ -327,6 +345,8 @@ TRUE TRUNC TTEST TYPE +UNICHAR +UNIORD UPPER USDOLLAR VALUE @@ -342,6 +362,7 @@ WEIBULL WORKDAY XIRR XNPV +XOR YEAR YEARFRAC YIELD diff --git a/tests/PhpSpreadsheetTests/Calculation/DateTimeTest.php b/tests/PhpSpreadsheetTests/Calculation/DateTimeTest.php index 3d4f9f31..a6d781a5 100644 --- a/tests/PhpSpreadsheetTests/Calculation/DateTimeTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/DateTimeTest.php @@ -155,6 +155,23 @@ class DateTimeTest extends TestCase return require 'data/Calculation/DateTime/WEEKNUM.php'; } + /** + * @dataProvider providerISOWEEKNUM + * + * @param mixed $expectedResult + * @param mixed $dateValue + */ + public function testISOWEEKNUM($expectedResult, $dateValue) + { + $result = DateTime::ISOWEEKNUM($dateValue); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerISOWEEKNUM() + { + return require 'data/Calculation/DateTime/ISOWEEKNUM.php'; + } + /** * @dataProvider providerWEEKDAY * diff --git a/tests/PhpSpreadsheetTests/Calculation/EngineeringTest.php b/tests/PhpSpreadsheetTests/Calculation/EngineeringTest.php index ae79d104..341083bf 100644 --- a/tests/PhpSpreadsheetTests/Calculation/EngineeringTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/EngineeringTest.php @@ -399,6 +399,22 @@ class EngineeringTest extends TestCase return require 'data/Calculation/Engineering/ERF.php'; } + /** + * @dataProvider providerERFPRECISE + * + * @param mixed $expectedResult + */ + public function testERFPRECISE($expectedResult, ...$args) + { + $result = Engineering::ERFPRECISE(...$args); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerERFPRECISE() + { + return require 'data/Calculation/Engineering/ERFPRECISE.php'; + } + /** * @dataProvider providerERFC * diff --git a/tests/PhpSpreadsheetTests/Calculation/FinancialTest.php b/tests/PhpSpreadsheetTests/Calculation/FinancialTest.php index 7b75676a..d9103896 100644 --- a/tests/PhpSpreadsheetTests/Calculation/FinancialTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/FinancialTest.php @@ -479,6 +479,38 @@ class FinancialTest extends TestCase return require 'data/Calculation/Financial/PRICE.php'; } + /** + * @dataProvider providerPRICEDISC + * + * @param mixed $expectedResult + */ + public function testPRICEDISC($expectedResult, array $args) + { + $result = Financial::PRICEDISC(...$args); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerPRICEDISC() + { + return require 'data/Calculation/Financial/PRICEDISC.php'; + } + + /** + * @dataProvider providerPV + * + * @param mixed $expectedResult + */ + public function testPV($expectedResult, array $args) + { + $result = Financial::PV(...$args); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerPV() + { + return require 'data/Calculation/Financial/PV.php'; + } + /** * @dataProvider providerRATE * @@ -514,4 +546,68 @@ class FinancialTest extends TestCase { return require 'data/Calculation/Financial/XIRR.php'; } + + /** + * @dataProvider providerPDURATION + * + * @param mixed $expectedResult + */ + public function testPDURATION($expectedResult, array $args) + { + $result = Financial::PDURATION(...$args); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerPDURATION() + { + return require 'data/Calculation/Financial/PDURATION.php'; + } + + /** + * @dataProvider providerRRI + * + * @param mixed $expectedResult + */ + public function testRRI($expectedResult, array $args) + { + $result = Financial::RRI(...$args); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerRRI() + { + return require 'data/Calculation/Financial/RRI.php'; + } + + /** + * @dataProvider providerSLN + * + * @param mixed $expectedResult + */ + public function testSLN($expectedResult, array $args) + { + $result = Financial::SLN(...$args); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerSLN() + { + return require 'data/Calculation/Financial/SLN.php'; + } + + /** + * @dataProvider providerSYD + * + * @param mixed $expectedResult + */ + public function testSYD($expectedResult, array $args) + { + $result = Financial::SYD(...$args); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerSYD() + { + return require 'data/Calculation/Financial/SYD.php'; + } } diff --git a/tests/PhpSpreadsheetTests/Calculation/FunctionsTest.php b/tests/PhpSpreadsheetTests/Calculation/FunctionsTest.php index 1255d910..df2028c0 100644 --- a/tests/PhpSpreadsheetTests/Calculation/FunctionsTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/FunctionsTest.php @@ -4,6 +4,7 @@ namespace PhpOffice\PhpSpreadsheetTests\Calculation; use PhpOffice\PhpSpreadsheet\Calculation\Functions; use PhpOffice\PhpSpreadsheet\Cell\Cell; +use PhpOffice\PhpSpreadsheet\Spreadsheet; use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet; use PHPUnit\Framework\TestCase; @@ -12,6 +13,49 @@ class FunctionsTest extends TestCase public function setUp() { Functions::setCompatibilityMode(Functions::COMPATIBILITY_EXCEL); + Functions::setReturnDateType(Functions::RETURNDATE_EXCEL); + } + + public function tearDown() + { + Functions::setCompatibilityMode(Functions::COMPATIBILITY_EXCEL); + Functions::setReturnDateType(Functions::RETURNDATE_EXCEL); + } + + public function testCompatibilityMode() + { + $result = Functions::setCompatibilityMode(Functions::COMPATIBILITY_GNUMERIC); + // Test for a true response for success + $this->assertTrue($result); + // Test that mode has been changed + $this->assertEquals(Functions::COMPATIBILITY_GNUMERIC, Functions::getCompatibilityMode()); + } + + public function testInvalidCompatibilityMode() + { + $result = Functions::setCompatibilityMode('INVALIDMODE'); + // Test for a false response for failure + $this->assertFalse($result); + // Test that mode has not been changed + $this->assertEquals(Functions::COMPATIBILITY_EXCEL, Functions::getCompatibilityMode()); + } + + public function testReturnDateType() + { + $result = Functions::setReturnDateType(Functions::RETURNDATE_PHP_OBJECT); + // Test for a true response for success + $this->assertTrue($result); + // Test that mode has been changed + $this->assertEquals(Functions::RETURNDATE_PHP_OBJECT, Functions::getReturnDateType()); + } + + public function testInvalidReturnDateType() + { + $result = Functions::setReturnDateType('INVALIDTYPE'); + // Test for a false response for failure + $this->assertFalse($result); + // Test that mode has not been changed + $this->assertEquals(Functions::RETURNDATE_EXCEL, Functions::getReturnDateType()); } public function testDUMMY() @@ -274,23 +318,38 @@ class FunctionsTest extends TestCase * @dataProvider providerIsFormula * * @param mixed $expectedResult - * @param mixed $value + * @param mixed $reference Reference to the cell we wish to test + * @param mixed $value Value of the cell we wish to test */ - public function testIsFormula($expectedResult, $value = 'undefined') + public function testIsFormula($expectedResult, $reference, $value = 'undefined') { $ourCell = null; if ($value !== 'undefined') { $remoteCell = $this->getMockBuilder(Cell::class) ->disableOriginalConstructor() ->getMock(); - $remoteCell->method('getValue') - ->will($this->returnValue($value)); + $remoteCell->method('isFormula') + ->will($this->returnValue(substr($value, 0, 1) == '=')); + + $remoteSheet = $this->getMockBuilder(Worksheet::class) + ->disableOriginalConstructor() + ->getMock(); + $remoteSheet->method('getCell') + ->will($this->returnValue($remoteCell)); + + $workbook = $this->getMockBuilder(Spreadsheet::class) + ->disableOriginalConstructor() + ->getMock(); + $workbook->method('getSheetByName') + ->will($this->returnValue($remoteSheet)); $sheet = $this->getMockBuilder(Worksheet::class) ->disableOriginalConstructor() ->getMock(); $sheet->method('getCell') ->will($this->returnValue($remoteCell)); + $sheet->method('getParent') + ->will($this->returnValue($workbook)); $ourCell = $this->getMockBuilder(Cell::class) ->disableOriginalConstructor() @@ -299,7 +358,7 @@ class FunctionsTest extends TestCase ->will($this->returnValue($sheet)); } - $result = Functions::isFormula($value, $ourCell); + $result = Functions::isFormula($reference, $ourCell); self::assertEquals($expectedResult, $result, null, 1E-8); } diff --git a/tests/PhpSpreadsheetTests/Calculation/LogicalTest.php b/tests/PhpSpreadsheetTests/Calculation/LogicalTest.php index abe28b77..3dec0c7f 100644 --- a/tests/PhpSpreadsheetTests/Calculation/LogicalTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/LogicalTest.php @@ -57,6 +57,22 @@ class LogicalTest extends TestCase return require 'data/Calculation/Logical/OR.php'; } + /** + * @dataProvider providerXOR + * + * @param mixed $expectedResult + */ + public function testXOR($expectedResult, ...$args) + { + $result = Logical::logicalXor(...$args); + self::assertEquals($expectedResult, $result); + } + + public function providerXOR() + { + return require 'data/Calculation/Logical/XOR.php'; + } + /** * @dataProvider providerNOT * diff --git a/tests/PhpSpreadsheetTests/Calculation/LookupRefTest.php b/tests/PhpSpreadsheetTests/Calculation/LookupRefTest.php index eef15e3a..e7c949fa 100644 --- a/tests/PhpSpreadsheetTests/Calculation/LookupRefTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/LookupRefTest.php @@ -4,6 +4,9 @@ namespace PhpOffice\PhpSpreadsheetTests\Calculation; use PhpOffice\PhpSpreadsheet\Calculation\Functions; use PhpOffice\PhpSpreadsheet\Calculation\LookupRef; +use PhpOffice\PhpSpreadsheet\Cell\Cell; +use PhpOffice\PhpSpreadsheet\Spreadsheet; +use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet; use PHPUnit\Framework\TestCase; /** @@ -111,4 +114,59 @@ class LookupRefTest extends TestCase { return require 'data/Calculation/LookupRef/ROWS.php'; } + + /** + * @dataProvider providerFormulaText + * + * @param mixed $expectedResult + * @param mixed $reference Reference to the cell we wish to test + * @param mixed $value Value of the cell we wish to test + */ + public function testFormulaText($expectedResult, $reference, $value = 'undefined') + { + $ourCell = null; + if ($value !== 'undefined') { + $remoteCell = $this->getMockBuilder(Cell::class) + ->disableOriginalConstructor() + ->getMock(); + $remoteCell->method('isFormula') + ->will($this->returnValue(substr($value, 0, 1) == '=')); + $remoteCell->method('getValue') + ->will($this->returnValue($value)); + + $remoteSheet = $this->getMockBuilder(Worksheet::class) + ->disableOriginalConstructor() + ->getMock(); + $remoteSheet->method('getCell') + ->will($this->returnValue($remoteCell)); + + $workbook = $this->getMockBuilder(Spreadsheet::class) + ->disableOriginalConstructor() + ->getMock(); + $workbook->method('getSheetByName') + ->will($this->returnValue($remoteSheet)); + + $sheet = $this->getMockBuilder(Worksheet::class) + ->disableOriginalConstructor() + ->getMock(); + $sheet->method('getCell') + ->will($this->returnValue($remoteCell)); + $sheet->method('getParent') + ->will($this->returnValue($workbook)); + + $ourCell = $this->getMockBuilder(Cell::class) + ->disableOriginalConstructor() + ->getMock(); + $ourCell->method('getWorksheet') + ->will($this->returnValue($sheet)); + } + + $result = LookupRef::FORMULATEXT($reference, $ourCell); + self::assertEquals($expectedResult, $result, null, 1E-8); + } + + public function providerFormulaText() + { + return require 'data/Calculation/LookupRef/FORMULATEXT.php'; + } } diff --git a/tests/PhpSpreadsheetTests/Calculation/MathTrigTest.php b/tests/PhpSpreadsheetTests/Calculation/MathTrigTest.php index dbe40664..fa497964 100644 --- a/tests/PhpSpreadsheetTests/Calculation/MathTrigTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/MathTrigTest.php @@ -440,6 +440,70 @@ class MathTrigTest extends TestCase return require 'data/Calculation/MathTrig/SUMSQ.php'; } + /** + * @dataProvider providerSUMPRODUCT + * + * @param mixed $expectedResult + */ + public function testSUMPRODUCT($expectedResult, ...$args) + { + $result = MathTrig::SUMPRODUCT(...$args); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerSUMPRODUCT() + { + return require 'data/Calculation/MathTrig/SUMPRODUCT.php'; + } + + /** + * @dataProvider providerSUMX2MY2 + * + * @param mixed $expectedResult + */ + public function testSUMX2MY2($expectedResult, ...$args) + { + $result = MathTrig::SUMX2MY2(...$args); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerSUMX2MY2() + { + return require 'data/Calculation/MathTrig/SUMX2MY2.php'; + } + + /** + * @dataProvider providerSUMX2PY2 + * + * @param mixed $expectedResult + */ + public function testSUMX2PY2($expectedResult, ...$args) + { + $result = MathTrig::SUMX2PY2(...$args); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerSUMX2PY2() + { + return require 'data/Calculation/MathTrig/SUMX2PY2.php'; + } + + /** + * @dataProvider providerSUMXMY2 + * + * @param mixed $expectedResult + */ + public function testSUMXMY2($expectedResult, ...$args) + { + $result = MathTrig::SUMXMY2(...$args); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerSUMXMY2() + { + return require 'data/Calculation/MathTrig/SUMXMY2.php'; + } + /** * @dataProvider providerTRUNC * @@ -678,4 +742,140 @@ class MathTrigTest extends TestCase { return require 'data/Calculation/MathTrig/SUBTOTALNESTED.php'; } + + /** + * @dataProvider providerSEC + * + * @param mixed $expectedResult + * @param mixed $angle + */ + public function testSEC($expectedResult, $angle) + { + $result = MathTrig::SEC($angle); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerSEC() + { + return require 'data/Calculation/MathTrig/SEC.php'; + } + + /** + * @dataProvider providerSECH + * + * @param mixed $expectedResult + * @param mixed $angle + */ + public function testSECH($expectedResult, $angle) + { + $result = MathTrig::SECH($angle); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerSECH() + { + return require 'data/Calculation/MathTrig/SECH.php'; + } + + /** + * @dataProvider providerCSC + * + * @param mixed $expectedResult + * @param mixed $angle + */ + public function testCSC($expectedResult, $angle) + { + $result = MathTrig::CSC($angle); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerCSC() + { + return require 'data/Calculation/MathTrig/CSC.php'; + } + + /** + * @dataProvider providerCSCH + * + * @param mixed $expectedResult + * @param mixed $angle + */ + public function testCSCH($expectedResult, $angle) + { + $result = MathTrig::CSCH($angle); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerCSCH() + { + return require 'data/Calculation/MathTrig/CSCH.php'; + } + + /** + * @dataProvider providerCOT + * + * @param mixed $expectedResult + * @param mixed $angle + */ + public function testCOT($expectedResult, $angle) + { + $result = MathTrig::COT($angle); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerCOT() + { + return require 'data/Calculation/MathTrig/COT.php'; + } + + /** + * @dataProvider providerCOTH + * + * @param mixed $expectedResult + * @param mixed $angle + */ + public function testCOTH($expectedResult, $angle) + { + $result = MathTrig::COTH($angle); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerCOTH() + { + return require 'data/Calculation/MathTrig/COTH.php'; + } + + /** + * @dataProvider providerACOT + * + * @param mixed $expectedResult + * @param mixed $number + */ + public function testACOT($expectedResult, $number) + { + $result = MathTrig::ACOT($number); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerACOT() + { + return require 'data/Calculation/MathTrig/ACOT.php'; + } + + /** + * @dataProvider providerACOTH + * + * @param mixed $expectedResult + * @param mixed $number + */ + public function testACOTH($expectedResult, $number) + { + $result = MathTrig::ACOTH($number); + self::assertEquals($expectedResult, $result, null, 1E-12); + } + + public function providerACOTH() + { + return require 'data/Calculation/MathTrig/ACOTH.php'; + } } diff --git a/tests/PhpSpreadsheetTests/Calculation/TextDataTest.php b/tests/PhpSpreadsheetTests/Calculation/TextDataTest.php index c6e8ad84..ffe5c68c 100644 --- a/tests/PhpSpreadsheetTests/Calculation/TextDataTest.php +++ b/tests/PhpSpreadsheetTests/Calculation/TextDataTest.php @@ -13,6 +13,17 @@ class TextDataTest extends TestCase public function setUp() { Functions::setCompatibilityMode(Functions::COMPATIBILITY_EXCEL); + StringHelper::setDecimalSeparator('.'); + StringHelper::setThousandsSeparator(','); + StringHelper::setCurrencyCode('$'); + } + + public function tearDown() + { + Functions::setCompatibilityMode(Functions::COMPATIBILITY_EXCEL); + StringHelper::setDecimalSeparator('.'); + StringHelper::setThousandsSeparator(','); + StringHelper::setCurrencyCode('$'); } /** @@ -383,4 +394,38 @@ class TextDataTest extends TestCase { return require 'data/Calculation/TextData/EXACT.php'; } + + /** + * @dataProvider providerTEXTJOIN + * + * @param mixed $expectedResult + * @param array $args + */ + public function testTEXTJOIN($expectedResult, array $args) + { + $result = TextData::TEXTJOIN(...$args); + self::assertEquals($expectedResult, $result); + } + + public function providerTEXTJOIN() + { + return require 'data/Calculation/TextData/TEXTJOIN.php'; + } + + /** + * @dataProvider providerNUMBERVALUE + * + * @param mixed $expectedResult + * @param array $args + */ + public function testNUMBERVALUE($expectedResult, array $args) + { + $result = TextData::NUMBERVALUE(...$args); + self::assertEquals($expectedResult, $result); + } + + public function providerNUMBERVALUE() + { + return require 'data/Calculation/TextData/NUMBERVALUE.php'; + } } diff --git a/tests/data/Calculation/DateTime/DATEVALUE.php b/tests/data/Calculation/DateTime/DATEVALUE.php index 656e9b7d..f38b9f98 100644 --- a/tests/data/Calculation/DateTime/DATEVALUE.php +++ b/tests/data/Calculation/DateTime/DATEVALUE.php @@ -290,4 +290,8 @@ return [ 0, '15:30:25', ], + [ + '#VALUE!', + 'ABCDEFGHIJKMNOPQRSTUVWXYZ', + ], ]; diff --git a/tests/data/Calculation/DateTime/ISOWEEKNUM.php b/tests/data/Calculation/DateTime/ISOWEEKNUM.php new file mode 100644 index 00000000..78a4d3e8 --- /dev/null +++ b/tests/data/Calculation/DateTime/ISOWEEKNUM.php @@ -0,0 +1,36 @@ + 0, 2 > 0, + ], + [ + true, + true, false, false, + ], + [ + true, + 1 > 0, 0 > 1, + ], + [ + true, + 0 > 1, 2 > 0, + ], + [ + false, + 0 > 1, 0 > 2, + ], + [ + false, + 1 > 0, 2 > 0, 0 > 1, 0 > 2, + ], + [ + true, + 1 > 0, 2 > 0, 3 > 0, 0 > 1, + ], + [ + false, + 'TRUE', + 1, + 0.5, + ], + [ + true, + 'FALSE', + 1.5, + 0, + ], + [ + '#VALUE!', + 'HELLO WORLD', + ], +]; diff --git a/tests/data/Calculation/LookupRef/FORMULATEXT.php b/tests/data/Calculation/LookupRef/FORMULATEXT.php new file mode 100644 index 00000000..30b2d6eb --- /dev/null +++ b/tests/data/Calculation/LookupRef/FORMULATEXT.php @@ -0,0 +1,34 @@ + ['A' => '=SUBTOTAL(1, A1:A2)'], 4 => ['A' => '=ROMAN(SUBTOTAL(1, A1:A2))'], 5 => ['A' => 'This is text containing "=" and "SUBTOTAL("'], + 6 => ['A' => '=AGGREGATE(1, A1:A2)'], ]; return [ diff --git a/tests/data/Calculation/MathTrig/SUMPRODUCT.php b/tests/data/Calculation/MathTrig/SUMPRODUCT.php new file mode 100644 index 00000000..3a75e033 --- /dev/null +++ b/tests/data/Calculation/MathTrig/SUMPRODUCT.php @@ -0,0 +1,19 @@ +