diff --git a/CHANGELOG.md b/CHANGELOG.md index a740cd0d21..00f19a8cd4 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -9,7 +9,7 @@ and this project adheres to [Semantic Versioning](https://semver.org). ### Added -- Nothing yet. +- CHOOSECOLS, CHOOSEROWS, DROP, TAKE, and EXPAND. [PR #4286](https://github.com/PHPOffice/PhpSpreadsheet/pull/4286) ### Changed diff --git a/docs/references/function-list-by-category.md b/docs/references/function-list-by-category.md index 458a59b39c..447c97367e 100644 --- a/docs/references/function-list-by-category.md +++ b/docs/references/function-list-by-category.md @@ -240,8 +240,12 @@ Excel Function | PhpSpreadsheet Function ADDRESS | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Address::cell AREAS | **Not yet Implemented** CHOOSE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Selection::CHOOSE +CHOOSECOLS | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::chooseCols +CHOOSEROWS | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::chooseRows COLUMN | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\RowColumnInformation::COLUMN COLUMNS | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\RowColumnInformation::COLUMNS +DROP | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::drop +EXPAND | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::expand FILTER | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Filter::filter FORMULATEXT | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Formula::text GETPIVOTDATA | **Not yet Implemented** @@ -257,6 +261,7 @@ ROWS | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\RowCo RTD | **Not yet Implemented** SORT | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Sort::sort SORTBY | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Sort::sortBy +TAKE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::take TRANSPOSE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Matrix::transpose UNIQUE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Unique::unique VLOOKUP | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\VLookup::lookup @@ -283,8 +288,6 @@ BASE | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Base:: CEILING | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Ceiling::ceiling CEILING.MATH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Ceiling::math CEILING.PRECISE | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Ceiling::precise -CHOOSECOLS | **Not yet Implemented** -CHOOSEROWS | **Not yet Implemented** COMBIN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Combinations::withoutRepetition COMBINA | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Combinations::withRepetition COS | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\Cosine::cos @@ -295,11 +298,9 @@ CSC | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\C CSCH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\Cosecant::csch DECIMAL | **Not yet Implemented** DEGREES | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Angle::toDegrees -DROP | **Not yet Implemented** ECMA.CEILING | **Not yet Implemented** EVEN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Round::even EXP | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Exp::evaluate -EXPAND | **Not yet Implemented** FACT | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Factorial::fact FACTDOUBLE | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Factorial::factDouble FLOOR | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Floor::floor @@ -353,7 +354,6 @@ SUMSQ | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\SumSqu SUMX2MY2 | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\SumSquares::sumXSquaredMinusYSquared SUMX2PY2 | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\SumSquares::sumXSquaredPlusYSquared SUMXMY2 | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\SumSquares::sumXMinusYSquared -TAKE | **Not yet Implemented** TAN | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\Tangent::tan TANH | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\Tangent::tanh TOCOL | **Not yet Implemented** diff --git a/docs/references/function-list-by-name.md b/docs/references/function-list-by-name.md index addc2e3e97..868da519a2 100644 --- a/docs/references/function-list-by-name.md +++ b/docs/references/function-list-by-name.md @@ -79,8 +79,8 @@ CHISQ.INV.RT | CATEGORY_STATISTICAL | \PhpOffice\PhpSpread CHISQ.TEST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical\Distributions\ChiSquared::test CHITEST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical\Distributions\ChiSquared::test CHOOSE | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\Selection::CHOOSE -CHOOSECOLS | CATEGORY_MATH_AND_TRIG | **Not yet Implemented** -CHOOSEROWS | CATEGORY_MATH_AND_TRIG | **Not yet Implemented** +CHOOSECOLS | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::chooseCols +CHOOSEROWS | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::chooseRows CLEAN | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData\Trim::nonPrintable CODE | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData\CharacterConvert::code COLUMN | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\RowColumnInformation::COLUMN @@ -158,7 +158,7 @@ DOLLAR | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpread DOLLARDE | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial\Dollar::decimal DOLLARFR | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial\Dollar::fractional DPRODUCT | CATEGORY_DATABASE | \PhpOffice\PhpSpreadsheet\Calculation\Database\DProduct::evaluate -DROP | CATEGORY_MATH_AND_TRIG | **Not yet Implemented** +DROP | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::drop DSTDEV | CATEGORY_DATABASE | \PhpOffice\PhpSpreadsheet\Calculation\Database\DStDev::evaluate DSTDEVP | CATEGORY_DATABASE | \PhpOffice\PhpSpreadsheet\Calculation\Database\DStDevP::evaluate DSUM | CATEGORY_DATABASE | \PhpOffice\PhpSpreadsheet\Calculation\Database\DSum::evaluate @@ -183,7 +183,7 @@ ERROR.TYPE | CATEGORY_INFORMATION | \PhpOffice\PhpSpread EVEN | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Round::even EXACT | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData\Text::exact EXP | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Exp::evaluate -EXPAND | CATEGORY_MATH_AND_TRIG | **Not yet Implemented** +EXPAND | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::expand EXPON.DIST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical\Distributions\Exponential::distribution EXPONDIST | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical\Distributions\Exponential::distribution @@ -553,7 +553,7 @@ T.DIST.RT | CATEGORY_STATISTICAL | **Not yet Implemente T.INV | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical\Distributions\StudentT::inverse T.INV.2T | CATEGORY_STATISTICAL | **Not yet Implemented** T.TEST | CATEGORY_STATISTICAL | **Not yet Implemented** -TAKE | CATEGORY_MATH_AND_TRIG | **Not yet Implemented** +TAKE | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef\ChooseRowsEtc::take TAN | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\Tangent::tan TANH | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig\Trig\Tangent::tanh TBILLEQ | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial\TreasuryBill::bondEquivalentYield diff --git a/src/PhpSpreadsheet/Calculation/Calculation.php b/src/PhpSpreadsheet/Calculation/Calculation.php index ab52fb1af9..c31ea2c749 100644 --- a/src/PhpSpreadsheet/Calculation/Calculation.php +++ b/src/PhpSpreadsheet/Calculation/Calculation.php @@ -553,13 +553,13 @@ public static function getExcelConstants(string $key): bool|null 'argumentCount' => '2+', ], 'CHOOSECOLS' => [ - 'category' => Category::CATEGORY_MATH_AND_TRIG, - 'functionCall' => [Functions::class, 'DUMMY'], + 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, + 'functionCall' => [LookupRef\ChooseRowsEtc::class, 'chooseCols'], 'argumentCount' => '2+', ], 'CHOOSEROWS' => [ - 'category' => Category::CATEGORY_MATH_AND_TRIG, - 'functionCall' => [Functions::class, 'DUMMY'], + 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, + 'functionCall' => [LookupRef\ChooseRowsEtc::class, 'chooseRows'], 'argumentCount' => '2+', ], 'CLEAN' => [ @@ -925,8 +925,8 @@ public static function getExcelConstants(string $key): bool|null 'argumentCount' => '3', ], 'DROP' => [ - 'category' => Category::CATEGORY_MATH_AND_TRIG, - 'functionCall' => [Functions::class, 'DUMMY'], + 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, + 'functionCall' => [LookupRef\ChooseRowsEtc::class, 'drop'], 'argumentCount' => '2-3', ], 'DSTDEV' => [ @@ -1025,8 +1025,8 @@ public static function getExcelConstants(string $key): bool|null 'argumentCount' => '1', ], 'EXPAND' => [ - 'category' => Category::CATEGORY_MATH_AND_TRIG, - 'functionCall' => [Functions::class, 'DUMMY'], + 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, + 'functionCall' => [LookupRef\ChooseRowsEtc::class, 'expand'], 'argumentCount' => '2-4', ], 'EXPONDIST' => [ @@ -2485,8 +2485,8 @@ public static function getExcelConstants(string $key): bool|null 'argumentCount' => '1', ], 'TAKE' => [ - 'category' => Category::CATEGORY_MATH_AND_TRIG, - 'functionCall' => [Functions::class, 'DUMMY'], + 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, + 'functionCall' => [LookupRef\ChooseRowsEtc::class, 'take'], 'argumentCount' => '2-3', ], 'TAN' => [ diff --git a/src/PhpSpreadsheet/Calculation/Functions.php b/src/PhpSpreadsheet/Calculation/Functions.php index 9a094966a3..5ee2dfd7a4 100644 --- a/src/PhpSpreadsheet/Calculation/Functions.php +++ b/src/PhpSpreadsheet/Calculation/Functions.php @@ -230,6 +230,32 @@ public static function flattenArray(mixed $array): array return $flattened; } + /** + * Convert a multi-dimensional array to a simple 1-dimensional array. + * Same as above but argument is specified in ... format. + * + * @param mixed $array Array to be flattened + * + * @return array Flattened array + */ + public static function flattenArray2(mixed ...$array): array + { + $flattened = []; + $stack = array_values($array); + + while (!empty($stack)) { + $value = array_shift($stack); + + if (is_array($value)) { + array_unshift($stack, ...array_values($value)); + } else { + $flattened[] = $value; + } + } + + return $flattened; + } + public static function scalar(mixed $value): mixed { if (!is_array($value)) { diff --git a/src/PhpSpreadsheet/Calculation/LookupRef/ChooseRowsEtc.php b/src/PhpSpreadsheet/Calculation/LookupRef/ChooseRowsEtc.php new file mode 100644 index 0000000000..97303e7533 --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/LookupRef/ChooseRowsEtc.php @@ -0,0 +1,241 @@ + [$x]) : null, ...$array)); // @phpstan-ignore-line + } + + /** @return mixed[] */ + private static function arrayValues(mixed $array): array + { + return is_array($array) ? array_values($array) : [$array]; + } + + /** + * CHOOSECOLS. + * + * @param mixed $input expecting two-dimensional array + * + * @return mixed[]|string + */ + public static function chooseCols(mixed $input, mixed ...$args): array|string + { + if (!is_array($input)) { + $input = [[$input]]; + } + $retval = self::chooseRows(self::transpose($input), ...$args); + + return is_array($retval) ? self::transpose($retval) : $retval; + } + + /** + * CHOOSEROWS. + * + * @param mixed $input expecting two-dimensional array + * + * @return mixed[]|string + */ + public static function chooseRows(mixed $input, mixed ...$args): array|string + { + if (!is_array($input)) { + $input = [[$input]]; + } + $inputArray = [[]]; // no row 0 + $numRows = 0; + foreach ($input as $inputRow) { + $inputArray[] = self::arrayValues($inputRow); + ++$numRows; + } + $outputArray = []; + foreach (Functions::flattenArray2(...$args) as $arg) { + if (!is_numeric($arg)) { + return ExcelError::VALUE(); + } + $index = (int) $arg; + if ($index < 0) { + $index += $numRows + 1; + } + if ($index <= 0 || $index > $numRows) { + return ExcelError::VALUE(); + } + $outputArray[] = $inputArray[$index]; + } + + return $outputArray; + } + + private static function dropRows(array $array, mixed $offset): array|string + { + if ($offset === null) { + return $array; + } + if (!is_numeric($offset)) { + return ExcelError::VALUE(); + } + $offset = (int) $offset; + $count = count($array); + if (abs($offset) >= $count) { + // In theory, this should be #CALC!, but Excel treats + // #CALC! as corrupt, and it's not worth figuring out why + return ExcelError::VALUE(); + } + if ($offset === 0) { + return $array; + } + if ($offset > 0) { + return array_slice($array, $offset); + } + + return array_slice($array, 0, $count + $offset); + } + + /** + * DROP. + * + * @param mixed $input expect two-dimensional array + * + * @return mixed[]|string + */ + public static function drop(mixed $input, mixed $rows = null, mixed $columns = null): array|string + { + if (!is_array($input)) { + $input = [[$input]]; + } + $inputArray = []; // no row 0 + foreach ($input as $inputRow) { + $inputArray[] = self::arrayValues($inputRow); + } + $outputArray1 = self::dropRows($inputArray, $rows); + if (is_string($outputArray1)) { + return $outputArray1; + } + $outputArray2 = self::transpose($outputArray1); + $outputArray3 = self::dropRows($outputArray2, $columns); + if (is_string($outputArray3)) { + return $outputArray3; + } + + return self::transpose($outputArray3); + } + + private static function takeRows(array $array, mixed $offset): array|string + { + if ($offset === null) { + return $array; + } + if (!is_numeric($offset)) { + return ExcelError::VALUE(); + } + $offset = (int) $offset; + if ($offset === 0) { + // should be #CALC! - see above + return ExcelError::VALUE(); + } + $count = count($array); + if (abs($offset) >= $count) { + return $array; + } + if ($offset > 0) { + return array_slice($array, 0, $offset); + } + + return array_slice($array, $count + $offset); + } + + /** + * TAKE. + * + * @param mixed $input expecting two-dimensional array + * + * @return mixed[]|string + */ + public static function take(mixed $input, mixed $rows, mixed $columns = null): array|string + { + if (!is_array($input)) { + $input = [[$input]]; + } + if ($rows === null && $columns === null) { + return $input; + } + $inputArray = []; + foreach ($input as $inputRow) { + $inputArray[] = self::arrayValues($inputRow); + } + $outputArray1 = self::takeRows($inputArray, $rows); + if (is_string($outputArray1)) { + return $outputArray1; + } + $outputArray2 = self::transpose($outputArray1); + $outputArray3 = self::takeRows($outputArray2, $columns); + if (is_string($outputArray3)) { + return $outputArray3; + } + + return self::transpose($outputArray3); + } + + /** + * EXPAND. + * + * @param mixed $input expecting two-dimensional array + * + * @return mixed[]|string + */ + public static function expand(mixed $input, mixed $rows, mixed $columns = null, mixed $pad = '#N/A'): array|string + { + if (!is_array($input)) { + $input = [[$input]]; + } + if ($rows === null && $columns === null) { + return $input; + } + $numRows = count($input); + $rows ??= $numRows; + if (!is_numeric($rows)) { + return ExcelError::VALUE(); + } + $rows = (int) $rows; + if ($rows < count($input)) { + return ExcelError::VALUE(); + } + $numCols = 0; + foreach ($input as $inputRow) { + $numCols = max($numCols, is_array($inputRow) ? count($inputRow) : 1); + } + $columns ??= $numCols; + if (!is_numeric($columns)) { + return ExcelError::VALUE(); + } + $columns = (int) $columns; + if ($columns < $numCols) { + return ExcelError::VALUE(); + } + $inputArray = []; + foreach ($input as $inputRow) { + $inputArray[] = array_pad(self::arrayValues($inputRow), $columns, $pad); + } + $outputArray = []; + $padRow = array_pad([], $columns, $pad); + for ($count = 0; $count < $rows; ++$count) { + $outputArray[] = ($count >= $numRows) ? $padRow : $inputArray[$count]; + } + + return $outputArray; + } +} diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/AllSetupTeardown.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/AllSetupTeardown.php index da8d350e4a..0f177c81f4 100644 --- a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/AllSetupTeardown.php +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/AllSetupTeardown.php @@ -4,6 +4,7 @@ namespace PhpOffice\PhpSpreadsheetTests\Calculation\Functions\LookupRef; +use PhpOffice\PhpSpreadsheet\Calculation\Calculation; use PhpOffice\PhpSpreadsheet\Calculation\Exception as CalcException; use PhpOffice\PhpSpreadsheet\Calculation\Functions; use PhpOffice\PhpSpreadsheet\Cell\DataType; @@ -15,6 +16,8 @@ class AllSetupTeardown extends TestCase { protected string $compatibilityMode; + protected string $arrayReturnType; + private ?Spreadsheet $spreadsheet = null; private ?Worksheet $sheet = null; @@ -22,11 +25,13 @@ class AllSetupTeardown extends TestCase protected function setUp(): void { $this->compatibilityMode = Functions::getCompatibilityMode(); + $this->arrayReturnType = Calculation::getArrayReturnType(); } protected function tearDown(): void { Functions::setCompatibilityMode($this->compatibilityMode); + Calculation::setArrayReturnType($this->arrayReturnType); $this->sheet = null; if ($this->spreadsheet !== null) { $this->spreadsheet->disconnectWorksheets(); diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ChooseColsTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ChooseColsTest.php new file mode 100644 index 0000000000..26c8eb45fb --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ChooseColsTest.php @@ -0,0 +1,54 @@ +mightHaveException($expectedResult); + $sheet = $this->getSheet(); + $sheet->fromArray( + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + null, + 'B3', + true + ); + $this->getSpreadsheet()->addNamedRange( + new NamedRange( + 'definedname', + $sheet, + '$B$3:$D$11' + ) + ); + + $sheet->setCellValue('F3', $formula); + $result = $sheet->getCell('F3')->getCalculatedValue(); + self::assertSame($expectedResult, $result); + } + + public static function providerChooseCols(): array + { + return require 'tests/data/Calculation/LookupRef/CHOOSECOLS.php'; + } +} diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ChooseRowsTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ChooseRowsTest.php new file mode 100644 index 0000000000..3766ea203b --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ChooseRowsTest.php @@ -0,0 +1,54 @@ +mightHaveException($expectedResult); + $sheet = $this->getSheet(); + $sheet->fromArray( + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + null, + 'B3', + true + ); + $this->getSpreadsheet()->addNamedRange( + new NamedRange( + 'definedname', + $sheet, + '$B$3:$D$11' + ) + ); + + $sheet->setCellValue('F3', $formula); + $result = $sheet->getCell('F3')->getCalculatedValue(); + self::assertSame($expectedResult, $result); + } + + public static function providerChooseRows(): array + { + return require 'tests/data/Calculation/LookupRef/CHOOSEROWS.php'; + } +} diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/DropTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/DropTest.php new file mode 100644 index 0000000000..0a8411464d --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/DropTest.php @@ -0,0 +1,54 @@ +mightHaveException($expectedResult); + $sheet = $this->getSheet(); + $sheet->fromArray( + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + null, + 'B3', + true + ); + $this->getSpreadsheet()->addNamedRange( + new NamedRange( + 'definedname', + $sheet, + '$B$3:$D$11' + ) + ); + + $sheet->setCellValue('F3', $formula); + $result = $sheet->getCell('F3')->getCalculatedValue(); + self::assertSame($expectedResult, $result); + } + + public static function providerDrop(): array + { + return require 'tests/data/Calculation/LookupRef/DROP.php'; + } +} diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ExpandTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ExpandTest.php new file mode 100644 index 0000000000..b68c64005b --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/ExpandTest.php @@ -0,0 +1,47 @@ +mightHaveException($expectedResult); + $sheet = $this->getSheet(); + $sheet->fromArray( + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ], + null, + 'B3', + true + ); + $this->getSpreadsheet()->addNamedRange( + new NamedRange( + 'definedname', + $sheet, + '$B$3:$D$11' + ) + ); + + $sheet->setCellValue('F3', $formula); + $result = $sheet->getCell('F3')->getCalculatedValue(); + self::assertSame($expectedResult, $result); + } + + public static function providerExpand(): array + { + return require 'tests/data/Calculation/LookupRef/EXPAND.php'; + } +} diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/TakeTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/TakeTest.php new file mode 100644 index 0000000000..d03187ecf0 --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/TakeTest.php @@ -0,0 +1,54 @@ +mightHaveException($expectedResult); + $sheet = $this->getSheet(); + $sheet->fromArray( + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + null, + 'B3', + true + ); + $this->getSpreadsheet()->addNamedRange( + new NamedRange( + 'definedname', + $sheet, + '$B$3:$D$11' + ) + ); + + $sheet->setCellValue('F3', $formula); + $result = $sheet->getCell('F3')->getCalculatedValue(); + self::assertSame($expectedResult, $result); + } + + public static function providerTake(): array + { + return require 'tests/data/Calculation/LookupRef/TAKE.php'; + } +} diff --git a/tests/data/Calculation/LookupRef/CHOOSECOLS.php b/tests/data/Calculation/LookupRef/CHOOSECOLS.php new file mode 100644 index 0000000000..b548382cc9 --- /dev/null +++ b/tests/data/Calculation/LookupRef/CHOOSECOLS.php @@ -0,0 +1,180 @@ + [ + [ + ['c'], + ['f'], + ['i'], + ['l'], + ['o'], + ['r'], + ['u'], + ['x'], + ['#'], + ], + '=CHOOSECOLS(B3:D11, -1)', + ], + 'select 1 column' => [ + [ + ['b'], + ['e'], + ['h'], + ['k'], + ['n'], + ['q'], + ['t'], + ['w'], + ['z'], + ], + '=CHOOSECOLS(B3:D11, 2)', + ], + 'fractional column' => [ + [ + ['b'], + ['e'], + ['h'], + ['k'], + ['n'], + ['q'], + ['t'], + ['w'], + ['z'], + ], + '=CHOOSECOLS(B3:D11, 2.8)', + ], + 'numeric string column' => [ + [ + ['b'], + ['e'], + ['h'], + ['k'], + ['n'], + ['q'], + ['t'], + ['w'], + ['z'], + ], + '=CHOOSECOLS(B3:D11, " 2.8 ")', + ], + 'multiple columns including duplicates' => [ + [ + ['b', 'a', 'b'], + ['e', 'd', 'e'], + ['h', 'g', 'h'], + ['k', 'j', 'k'], + ['n', 'm', 'n'], + ['q', 'p', 'q'], + ['t', 's', 't'], + ['w', 'v', 'w'], + ['z', 'y', 'z'], + ], + '=CHOOSECOLS(B3:D11, 2, 1, 2)', + ], + 'multiple columns mixed +/- mixed scalar/matrix' => [ + [ + ['b', 'a', 'b'], + ['e', 'd', 'e'], + ['h', 'g', 'h'], + ['k', 'j', 'k'], + ['n', 'm', 'n'], + ['q', 'p', 'q'], + ['t', 's', 't'], + ['w', 'v', 'w'], + ['z', 'y', 'z'], + ], + '=CHOOSECOLS(B3:D11, 2, {-3, 2})', + ], + 'reverse Columns' => [ + [ + ['c', 'b', 'a'], + ['f', 'e', 'd'], + ['i', 'h', 'g'], + ['l', 'k', 'j'], + ['o', 'n', 'm'], + ['r', 'q', 'p'], + ['u', 't', 's'], + ['x', 'w', 'v'], + ['#', 'z', 'y'], + ], + '=CHOOSECOLS(B3:D11, SEQUENCE(COLUMNS(B3:D11),,COLUMNS(B3:D11),-1))', + ], + 'inline array' => [ + [ + ['c', 'b'], + ['f', 'e'], + ['i', 'h'], + ['l', 'k'], + ['o', 'n'], + ['r', 'q'], + ['u', 't'], + ['x', 'w'], + ['#', 'z'], + ], + '=CHOOSECOLS(B3:D11, {3;2})', + ], + 'inline array with negative numbers' => [ + [ + ['b', 'c'], + ['e', 'f'], + ['h', 'i'], + ['k', 'l'], + ['n', 'o'], + ['q', 'r'], + ['t', 'u'], + ['w', 'x'], + ['z', '#'], + ], + '=CHOOSECOLS(B3:D11, {-2;-1})', + ], + 'defined name' => [ + [ + ['b', 'c'], + ['e', 'f'], + ['h', 'i'], + ['k', 'l'], + ['n', 'o'], + ['q', 'r'], + ['t', 'u'], + ['w', 'x'], + ['z', '#'], + ], + '=CHOOSECOLS(definedname, {-2;-1})', + ], + 'only 1 argument' => [ + 'exception', + '=CHOOSECOLS(B3:D11)', + ], + 'non-numeric column' => [ + '#VALUE!', + '=CHOOSECOLS(B3:D11, "x")', + ], + 'positive column too large' => [ + '#VALUE!', + '=CHOOSECOLS(B3:D11, 4)', + ], + 'negative column too large' => [ + '#VALUE!', + '=CHOOSECOLS(B3:D11, 1, -4)', + ], + 'zero column' => [ + '#VALUE!', + '=CHOOSECOLS(B3:D11, 0)', + ], + 'single cell' => [ + [ + ['a'], + ], + '=CHOOSECOLS(B3, 1)', + ], + 'inline array rather than range' => [ + [ + [2, 1, 1], + [4, 3, 3], + [6, 5, 5], + ], + '=CHOOSECOLS({1,2;3,4;5,6}, " 2.4 ", 1, 1)', + ], +]; diff --git a/tests/data/Calculation/LookupRef/CHOOSEROWS.php b/tests/data/Calculation/LookupRef/CHOOSEROWS.php new file mode 100644 index 0000000000..1f0e456268 --- /dev/null +++ b/tests/data/Calculation/LookupRef/CHOOSEROWS.php @@ -0,0 +1,115 @@ + [ + [ + ['y', 'z', '#'], + ], + '=CHOOSEROWS(B3:D11, -1)', + ], + 'fractional row' => [ + [ + ['y', 'z', '#'], + ], + '=CHOOSEROWS(B3:D11, -1.8)', + ], + 'numeric string row' => [ + [ + ['y', 'z', '#'], + ], + '=CHOOSEROWS(B3:D11, " -1.8 ")', + ], + 'select 1 row' => [ + [ + ['d', 'e', 'f'], + ], + '=CHOOSEROWS(B3:D11, 2)', + ], + 'multiple rows including duplicates' => [ + [ + ['d', 'e', 'f'], + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ], + '=CHOOSEROWS(B3:D11, 2, 1, 2)', + ], + 'multiple rows mixed +/- mixed scalar/matrix' => [ + [ + ['d', 'e', 'f'], + ['s', 't', 'u'], + ['d', 'e', 'f'], + ], + '=CHOOSEROWS(B3:D11, 2, {-3; 2})', + ], + 'reverse Rows' => [ + [ + ['y', 'z', '#'], + ['v', 'w', 'x'], + ['s', 't', 'u'], + ['p', 'q', 'r'], + ['m', 'n', 'o'], + ['j', 'k', 'l'], + ['g', 'h', 'i'], + ['d', 'e', 'f'], + ['a', 'b', 'c'], + ], + '=CHOOSEROWS(B3:D11, SEQUENCE(ROWS(B3:D11),,ROWS(B3:D11),-1))', + ], + 'inline array' => [ + [ + ['g', 'h', 'i'], + ['d', 'e', 'f'], + ], + '=CHOOSEROWS(B3:D11, {3;2})', + ], + 'inline array with negative numbers' => [ + [ + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=CHOOSEROWS(B3:D11, {-2;-1})', + ], + 'named range' => [ + [ + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=CHOOSEROWS(definedname, {-2;-1})', + ], + 'only 1 argument' => [ + 'exception', + '=CHOOSEROWS(B3:D11)', + ], + 'non-numeric row' => [ + '#VALUE!', + '=CHOOSEROWS(B3:D11, "x")', + ], + 'positive row too large' => [ + '#VALUE!', + '=CHOOSEROWS(B3:D11, 10)', + ], + 'negative row too large' => [ + '#VALUE!', + '=CHOOSEROWS(B3:D11, 1, -10)', + ], + 'zero row' => [ + '#VALUE!', + '=CHOOSEROWS(B3:D11, 0)', + ], + 'single cell' => [ + [ + ['a'], + ], + '=CHOOSEROWS(B3, 1)', + ], + 'inline array rather than range' => [ + [ + [3, 4], + [1, 2], + [1, 2], + ], + '=CHOOSEROWS({1,2;3,4;5,6}, " 2.4 ", 1, 1)', + ], +]; diff --git a/tests/data/Calculation/LookupRef/DROP.php b/tests/data/Calculation/LookupRef/DROP.php new file mode 100644 index 0000000000..628315772e --- /dev/null +++ b/tests/data/Calculation/LookupRef/DROP.php @@ -0,0 +1,178 @@ + [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ], + '=DROP(B3:D11, -1)', + ], + 'drop first 2 rows' => [ + [ + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=DROP(B3:D11, 2)', + ], + 'drop last 2 columns' => [ + [ + ['a'], + ['d'], + ['g'], + ['j'], + ['m'], + ['p'], + ['s'], + ['v'], + ['y'], + ], + '=DROP(B3:D11, , -2)', + ], + 'drop first column' => [ + [ + ['b', 'c'], + ['e', 'f'], + ['h', 'i'], + ['k', 'l'], + ['n', 'o'], + ['q', 'r'], + ['t', 'u'], + ['w', 'x'], + ['z', '#'], + ], + '=DROP(B3:D11, , 1)', + ], + 'drop last row first column' => [ + [ + ['b', 'c'], + ['e', 'f'], + ['h', 'i'], + ['k', 'l'], + ['n', 'o'], + ['q', 'r'], + ['t', 'u'], + ['w', 'x'], + ], + '=DROP(B3:D11, -1, 1)', + ], + 'drop first 2 rows last 2 columns' => [ + [ + ['g'], + ['j'], + ['m'], + ['p'], + ['s'], + ['v'], + ['y'], + ], + '=DROP(B3:D11, 2, -2)', + ], + 'drop first 2 rows last 2 columns fractional and string' => [ + [ + ['g'], + ['j'], + ['m'], + ['p'], + ['s'], + ['v'], + ['y'], + ], + '=DROP(B3:D11, 2.8, " -2.8 ")', + ], + 'named range' => [ + [ + ['g'], + ['j'], + ['m'], + ['p'], + ['s'], + ['v'], + ['y'], + ], + '=DROP(definedname, 2,-2)', + ], + 'only 1 argument' => [ + 'exception', + '=DROP(B3:D11)', + ], + 'non-numeric row' => [ + '#VALUE!', + '=DROP(B3:D11, "x")', + ], + 'non-numeric column' => [ + '#VALUE!', + '=DROP(B3:D11, 1, "x")', + ], + 'positive row too large' => [ + '#VALUE!', + '=DROP(B3:D11, 20)', + ], + 'negative row too large' => [ + '#VALUE!', + '=DROP(B3:D11, -20)', + ], + 'positive column too large' => [ + '#VALUE!', + '=DROP(B3:D11, , 20)', + ], + 'negative column too large' => [ + '#VALUE!', + '=DROP(B3:D11, , -20)', + ], + 'row okay column too large' => [ + '#VALUE!', + '=DROP(B3:D11, -1, 20)', + ], + 'zero row' => [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=DROP(B3:D11, 0)', + ], + 'zero column' => [ + [ + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=DROP(B3:D11, 1, 0)', + ], + 'single cell' => [ + '#VALUE!', + '=DROP(B3, 1)', + ], + 'inline array rather than range' => [ + [ + [4], + [6], + ], + '=DROP({1,2;3,4;5,6}, 1, 1)', + ], +]; diff --git a/tests/data/Calculation/LookupRef/EXPAND.php b/tests/data/Calculation/LookupRef/EXPAND.php new file mode 100644 index 0000000000..d00f7a7005 --- /dev/null +++ b/tests/data/Calculation/LookupRef/EXPAND.php @@ -0,0 +1,74 @@ + [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['#N/A', '#N/A', '#N/A'], + ['#N/A', '#N/A', '#N/A'], + ], + '=EXPAND(B3:D4, 4)', + ], + 'Add 1 colun' => [ + [ + ['a', 'b', 'c', '#N/A'], + ['d', 'e', 'f', '#N/A'], + ], + '=EXPAND(B3:D4, , 4)', + ], + 'Add 1 row 2 columns set cells to 0' => [ + [ + ['a', 'b', 'c', 0, 0], + ['d', 'e', 'f', 0, 0], + [0, 0, 0, 0, 0], + ], + '=EXPAND(B3:D4, 3, 5, 0)', + ], + 'Fractional row and column' => [ + [ + ['a', 'b', 'c', 0, 0], + ['d', 'e', 'f', 0, 0], + [0, 0, 0, 0, 0], + ], + '=EXPAND(B3:D4, 3.2, 5.8, 0)', + ], + 'only 1 argument' => [ + 'exception', + '=EXPAND(B3:D4)', + ], + 'non-numeric row' => [ + '#VALUE!', + '=EXPAND(B3:D4, "x")', + ], + 'non-numeric column' => [ + '#VALUE!', + '=EXPAND(B3:D4, 1, "x")', + ], + 'row too small' => [ + '#VALUE!', + '=EXPAND(B3:D4, 1)', + ], + 'column too small' => [ + '#VALUE!', + '=EXPAND(B3:D4, , 2)', + ], + 'single cell' => [ + [ + ['a', 'xx'], + ['xx', 'xx'], + ], + '=EXPAND(B3, 2, 2, "xx")', + ], + 'inline array rather than range' => [ + [ + [1, 2, 0, 0], + [3, 4, 0, 0], + [5, 6, 0, 0], + [0, 0, 0, 0], + ], + '=EXPAND({1,2;3,4;5,6}, 4.4, " 4.5 ", 0)', + ], +]; diff --git a/tests/data/Calculation/LookupRef/TAKE.php b/tests/data/Calculation/LookupRef/TAKE.php new file mode 100644 index 0000000000..b5ed8cf472 --- /dev/null +++ b/tests/data/Calculation/LookupRef/TAKE.php @@ -0,0 +1,168 @@ + [ + [ + ['y', 'z', '#'], + ], + '=TAKE(B3:D11, -1)', + ], + 'take first 2 rows' => [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ], + '=TAKE(B3:D11, 2)', + ], + 'take last 2 columns' => [ + [ + ['b', 'c'], + ['e', 'f'], + ['h', 'i'], + ['k', 'l'], + ['n', 'o'], + ['q', 'r'], + ['t', 'u'], + ['w', 'x'], + ['z', '#'], + ], + '=TAKE(B3:D11, , -2)', + ], + 'take first column' => [ + [ + ['a'], + ['d'], + ['g'], + ['j'], + ['m'], + ['p'], + ['s'], + ['v'], + ['y'], + ], + '=TAKE(B3:D11, , 1)', + ], + 'take last row first column' => [ + [ + ['y'], + ], + '=TAKE(B3:D11, -1, 1)', + ], + 'take first 2 rows last 2 columns' => [ + [ + ['b', 'c'], + ['e', 'f'], + ], + '=TAKE(B3:D11, 2, -2)', + ], + 'take first 2 rows last 2 columns fractional and string' => [ + [ + ['b', 'c'], + ['e', 'f'], + ], + '=TAKE(B3:D11, 2.8, " -2.8 ")', + ], + 'named range' => [ + [ + ['x'], + ['#'], + ], + '=TAKE(definedname, -2,-1)', + ], + 'only 1 argument' => [ + 'exception', + '=TAKE(B3:D11)', + ], + 'non-numeric row' => [ + '#VALUE!', + '=TAKE(B3:D11, "x")', + ], + 'non-numeric column' => [ + '#VALUE!', + '=TAKE(B3:D11, 1, "x")', + ], + 'positive row too large' => [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=TAKE(B3:D11, 20)', + ], + 'negative row too large' => [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=TAKE(B3:D11, -20)', + ], + 'positive column too large' => [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=TAKE(B3:D11, , 20)', + ], + 'negative column too large' => [ + [ + ['a', 'b', 'c'], + ['d', 'e', 'f'], + ['g', 'h', 'i'], + ['j', 'k', 'l'], + ['m', 'n', 'o'], + ['p', 'q', 'r'], + ['s', 't', 'u'], + ['v', 'w', 'x'], + ['y', 'z', '#'], + ], + '=TAKE(B3:D11, , -20)', + ], + 'row okay column too large' => [ + [ + ['y', 'z', '#'], + ], + '=TAKE(B3:D11, -1, 20)', + ], + 'zero row' => [ + '#VALUE!', + '=TAKE(B3:D11, 0)', + ], + 'zero column' => [ + '#VALUE!', + '=TAKE(B3:D11, 1, 0)', + ], + 'single cell' => [ + [ + ['a'], + ], + '=TAKE(B3, 1)', + ], + 'inline array rather than range' => [ + [ + [1, 2], + ], + '=TAKE({1,2;3,4;5,6}, 1, 2)', + ], +];