From 07f4fbe39629ce5c5d3a1c936e4e1b7d65ce9cb5 Mon Sep 17 00:00:00 2001 From: MarkBaker Date: Fri, 29 Jul 2022 18:33:12 +0200 Subject: [PATCH] Initial implementation of the `TEXTSPLIT()` Excel Function --- CHANGELOG.md | 2 +- .../Calculation/Calculation.php | 5 +- .../Calculation/TextData/Text.php | 130 ++++++++++++++++++ src/PhpSpreadsheet/Writer/Xlsx/Xlfn.php | 1 + .../Functions/TextData/TextSplitTest.php | 60 ++++++++ tests/data/Calculation/TextData/TEXTSPLIT.php | 107 ++++++++++++++ 6 files changed, 301 insertions(+), 4 deletions(-) create mode 100644 tests/PhpSpreadsheetTests/Calculation/Functions/TextData/TextSplitTest.php create mode 100644 tests/data/Calculation/TextData/TEXTSPLIT.php diff --git a/CHANGELOG.md b/CHANGELOG.md index 206892ad..017e31ed 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -9,7 +9,7 @@ and this project adheres to [Semantic Versioning](https://semver.org). ### Added -- Implementation of the `TEXTBEFORE()` and `TEXTAFTER()` Excel Functions +- Implementation of the new `TEXTBEFORE()`, `TEXTAFTER()` and `TEXTSPLIT()` Excel Functions ### Changed diff --git a/src/PhpSpreadsheet/Calculation/Calculation.php b/src/PhpSpreadsheet/Calculation/Calculation.php index b73c7eaa..13f38f66 100644 --- a/src/PhpSpreadsheet/Calculation/Calculation.php +++ b/src/PhpSpreadsheet/Calculation/Calculation.php @@ -7,7 +7,6 @@ use PhpOffice\PhpSpreadsheet\Calculation\Engine\CyclicReferenceStack; use PhpOffice\PhpSpreadsheet\Calculation\Engine\Logger; use PhpOffice\PhpSpreadsheet\Calculation\Information\ErrorValue; use PhpOffice\PhpSpreadsheet\Calculation\Information\ExcelError; -use PhpOffice\PhpSpreadsheet\Calculation\Information\Value; use PhpOffice\PhpSpreadsheet\Calculation\Token\Stack; use PhpOffice\PhpSpreadsheet\Cell\Cell; use PhpOffice\PhpSpreadsheet\Cell\Coordinate; @@ -2505,8 +2504,8 @@ class Calculation ], 'TEXTSPLIT' => [ 'category' => Category::CATEGORY_TEXT_AND_DATA, - 'functionCall' => [Functions::class, 'DUMMY'], - 'argumentCount' => '2-5', + 'functionCall' => [TextData\Text::class, 'split'], + 'argumentCount' => '2-6', ], 'THAIDAYOFWEEK' => [ 'category' => Category::CATEGORY_DATE_AND_TIME, diff --git a/src/PhpSpreadsheet/Calculation/TextData/Text.php b/src/PhpSpreadsheet/Calculation/TextData/Text.php index 490c43c2..bd533f20 100644 --- a/src/PhpSpreadsheet/Calculation/TextData/Text.php +++ b/src/PhpSpreadsheet/Calculation/TextData/Text.php @@ -3,6 +3,7 @@ namespace PhpOffice\PhpSpreadsheet\Calculation\TextData; use PhpOffice\PhpSpreadsheet\Calculation\ArrayEnabled; +use PhpOffice\PhpSpreadsheet\Calculation\Functions; class Text { @@ -77,4 +78,133 @@ class Text return null; } + + /** + * TEXTSPLIT. + * + * @param mixed $text the text that you're searching + * @param null|array|string $columnDelimiter The text that marks the point where to spill the text across columns. + * Multiple delimiters can be passed as an array of string values + * @param null|array|string $rowDelimiter The text that marks the point where to spill the text down rows. + * Multiple delimiters can be passed as an array of string values + * @param bool $ignoreEmpty Specify FALSE to create an empty cell when two delimiters are consecutive. + * true = create empty cells + * false = skip empty cells + * Defaults to TRUE, which creates an empty cell + * @param bool $matchMode Determines whether the match is case-sensitive or not. + * true = case-sensitive + * false = case-insensitive + * By default, a case-sensitive match is done. + * @param mixed $padding The value with which to pad the result. + * The default is #N/A. + * + * @return array the array built from the text, split by the row and column delimiters + */ + public static function split($text, $columnDelimiter = null, $rowDelimiter = null, bool $ignoreEmpty = false, bool $matchMode = true, $padding = '#N/A') + { + $text = Functions::flattenSingleValue($text); + + $flags = self::matchFlags($matchMode); + + if ($rowDelimiter !== null) { + $delimiter = self::buildDelimiter($rowDelimiter); + $rows = ($delimiter === '()') + ? [$text] + : preg_split("/{$delimiter}/{$flags}", $text); + } else { + $rows = [$text]; + } + + /** @var array $rows */ + if ($ignoreEmpty === true) { + $rows = array_values(array_filter( + $rows, + function ($row) { + return $row !== ''; + } + )); + } + + if ($columnDelimiter !== null) { + $delimiter = self::buildDelimiter($columnDelimiter); + array_walk( + $rows, + function (&$row) use ($delimiter, $flags, $ignoreEmpty): void { + $row = ($delimiter === '()') + ? [$row] + : preg_split("/{$delimiter}/{$flags}", $row); + /** @var array $row */ + if ($ignoreEmpty === true) { + $row = array_values(array_filter( + $row, + function ($value) { + return $value !== ''; + } + )); + } + } + ); + if ($ignoreEmpty === true) { + $rows = array_values(array_filter( + $rows, + function ($row) { + return $row !== [] && $row !== ['']; + } + )); + } + } + + return self::applyPadding($rows, $padding); + } + + /** + * @param mixed $padding + */ + private static function applyPadding(array $rows, $padding): array + { + $columnCount = array_reduce( + $rows, + function (int $counter, array $row): int { + return max($counter, count($row)); + }, + 0 + ); + + return array_map( + function (array $row) use ($columnCount, $padding): array { + return (count($row) < $columnCount) + ? array_merge($row, array_fill(0, $columnCount - count($row), $padding)) + : $row; + }, + $rows + ); + } + + /** + * @param null|array|string $delimiter the text that marks the point before which you want to split + * Multiple delimiters can be passed as an array of string values + */ + private static function buildDelimiter($delimiter): string + { + $valueSet = Functions::flattenArray($delimiter); + + if (is_array($delimiter) && count($valueSet) > 1) { + $quotedDelimiters = array_map( + function ($delimiter) { + return preg_quote($delimiter ?? ''); + }, + $valueSet + ); + $delimiters = implode('|', $quotedDelimiters); + + return '(' . $delimiters . ')'; + } + + return '(' . preg_quote(Functions::flattenSingleValue($delimiter)) . ')'; + } + + private static function matchFlags(bool $matchMode): string + { + return ($matchMode === true) ? 'miu' : 'mu'; + } } diff --git a/src/PhpSpreadsheet/Writer/Xlsx/Xlfn.php b/src/PhpSpreadsheet/Writer/Xlsx/Xlfn.php index b623c573..a1bdf96a 100644 --- a/src/PhpSpreadsheet/Writer/Xlsx/Xlfn.php +++ b/src/PhpSpreadsheet/Writer/Xlsx/Xlfn.php @@ -146,6 +146,7 @@ class Xlfn . '|register[.]id' . '|textafter' . '|textbefore' + . '|textsplit' . '|valuetotext' . ')(?=\\s*[(])/i'; diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/TextData/TextSplitTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/TextData/TextSplitTest.php new file mode 100644 index 00000000..e0fec8b9 --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/TextData/TextSplitTest.php @@ -0,0 +1,60 @@ + $value) { + ++$index; + $worksheet->getCell("{$column}{$index}")->setValue($value); + } + } else { + $worksheet->getCell("{$column}1")->setValue($argument); + } + } + + /** + * @dataProvider providerTEXTSPLIT + */ + public function testTextSplit(array $expectedResult, array $arguments): void + { + $text = $arguments[0]; + $columnDelimiter = $arguments[1]; + $rowDelimiter = $arguments[2]; + + $args = 'A1'; + $args .= (is_array($columnDelimiter)) ? ', ' . $this->setDelimiterArgument($columnDelimiter, 'B') : ', B1'; + $args .= (is_array($rowDelimiter)) ? ', ' . $this->setDelimiterArgument($rowDelimiter, 'C') : ', C1'; + $args .= (isset($arguments[3])) ? ", {$arguments[3]}" : ','; + $args .= (isset($arguments[4])) ? ", {$arguments[4]}" : ','; + $args .= (isset($arguments[5])) ? ", {$arguments[5]}" : ','; + + $worksheet = $this->getSheet(); + $worksheet->getCell('A1')->setValue($text); + $this->setDelimiterValues($worksheet, 'B', $columnDelimiter); + $this->setDelimiterValues($worksheet, 'C', $rowDelimiter); + $worksheet->getCell('H1')->setValue("=TEXTSPLIT({$args})"); + + $result = Calculation::getInstance($this->getSpreadsheet())->calculateCellValue($worksheet->getCell('H1')); + self::assertSame($expectedResult, $result); + } + + public function providerTEXTSPLIT(): array + { + return require 'tests/data/Calculation/TextData/TEXTSPLIT.php'; + } +} diff --git a/tests/data/Calculation/TextData/TEXTSPLIT.php b/tests/data/Calculation/TextData/TEXTSPLIT.php new file mode 100644 index 00000000..64016ca7 --- /dev/null +++ b/tests/data/Calculation/TextData/TEXTSPLIT.php @@ -0,0 +1,107 @@ +