From f3bb61f3e413906fc79f22c6d87745783b1e88bd Mon Sep 17 00:00:00 2001 From: MarkBaker Date: Sun, 20 Mar 2022 14:03:36 +0100 Subject: [PATCH] Initial work implementing the FILTER() Lookup/Reference function Tighten up on vector formats; and provide a couple of helper methods for testing row/column vectors --- CHANGELOG.md | 2 +- .../Calculation/Calculation.php | 2 +- .../Calculation/LookupRef/Filter.php | 65 ++++++++++++++ .../Calculation/LookupRef/Matrix.php | 17 ++++ .../Calculation/LookupRef/Unique.php | 4 +- .../Functions/LookupRef/FilterTest.php | 85 +++++++++++++++++++ .../LookupRef/MatrixHelperFunctionsTest.php | 77 +++++++++++++++++ 7 files changed, 248 insertions(+), 4 deletions(-) create mode 100644 src/PhpSpreadsheet/Calculation/LookupRef/Filter.php create mode 100644 tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/FilterTest.php create mode 100644 tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/MatrixHelperFunctionsTest.php diff --git a/CHANGELOG.md b/CHANGELOG.md index 500d1ac4..3ac8c9a9 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 UNIQUE() Lookup/Reference (array) function +- Implementation of the FILTER() and UNIQUE() Lookup/Reference (array) function - Implementation of the ISREF() Information function. - Added support for reading "formatted" numeric values from Csv files; although default behaviour of reading these values as strings is preserved. diff --git a/src/PhpSpreadsheet/Calculation/Calculation.php b/src/PhpSpreadsheet/Calculation/Calculation.php index b3988260..0f94a7e7 100644 --- a/src/PhpSpreadsheet/Calculation/Calculation.php +++ b/src/PhpSpreadsheet/Calculation/Calculation.php @@ -1040,7 +1040,7 @@ class Calculation ], 'FILTER' => [ 'category' => Category::CATEGORY_LOOKUP_AND_REFERENCE, - 'functionCall' => [Functions::class, 'DUMMY'], + 'functionCall' => [LookupRef\Filter::class, 'filter'], 'argumentCount' => '2-3', ], 'FILTERXML' => [ diff --git a/src/PhpSpreadsheet/Calculation/LookupRef/Filter.php b/src/PhpSpreadsheet/Calculation/LookupRef/Filter.php new file mode 100644 index 00000000..a5e7dc17 --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/LookupRef/Filter.php @@ -0,0 +1,65 @@ + 1 && + (count($values, COUNT_NORMAL) === 1 || count($values, COUNT_RECURSIVE) === count($values, COUNT_NORMAL)); + } + /** * TRANSPOSE. * diff --git a/src/PhpSpreadsheet/Calculation/LookupRef/Unique.php b/src/PhpSpreadsheet/Calculation/LookupRef/Unique.php index 67b911aa..2ba51281 100644 --- a/src/PhpSpreadsheet/Calculation/LookupRef/Unique.php +++ b/src/PhpSpreadsheet/Calculation/LookupRef/Unique.php @@ -29,8 +29,8 @@ class Unique $exactlyOnce = (bool) $exactlyOnce; return ($byColumn === true) - ? self::uniqueByColumn($lookupVector, $exactlyOnce) - : self::uniqueByRow($lookupVector, $exactlyOnce); + ? self::uniqueByColumn($lookupVector, $exactlyOnce) + : self::uniqueByRow($lookupVector, $exactlyOnce); } /** diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/FilterTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/FilterTest.php new file mode 100644 index 00000000..710a42e0 --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/FilterTest.php @@ -0,0 +1,85 @@ +sampleDataForRow(), $criteria); + self::assertSame($expectedResult, $result); + } + + public function testFilterByColumn(): void + { + $criteria = [[false, false, true, false, true, false, false, false, true, true]]; + $expectedResult = [ + ['Betty', 'Charlotte', 'Oliver', 'Zoe'], + ['B', 'B', 'B', 'B'], + [1, 2, 4, 8], + ]; + $result = Filter::filter($this->sampleDataForColumn(), $criteria); + self::assertSame($expectedResult, $result); + } + + public function testFilterException(): void + { + $criteria = 'INVALID'; + $result = Filter::filter($this->sampleDataForColumn(), $criteria); + self::assertSame(ExcelError::VALUE(), $result); + } + + public function testFilterEmpty(): void + { + $criteria = [[false], [false], [false]]; + $expectedResult = ExcelError::CALC(); + $result = Filter::filter([[1], [2], [3]], $criteria); + self::assertSame($expectedResult, $result); + + $expectedResult = 'Invalid Data'; + $result = Filter::filter([[1], [2], [3]], $criteria, $expectedResult); + self::assertSame($expectedResult, $result); + } + + protected function sampleDataForRow(): array + { + return [ + ['East', 'Tom', 'Apple', 6830], + ['West', 'Fred', 'Grape', 5619], + ['North', 'Amy', 'Pear', 4565], + ['South', 'Sal', 'Banana', 5323], + ['East', 'Fritz', 'Apple', 4394], + ['West', 'Sravan', 'Grape', 7195], + ['North', 'Xi', 'Pear', 5231], + ['South', 'Hector', 'Banana', 2427], + ['East', 'Tom', 'Banana', 4213], + ['West', 'Fred', 'Pear', 3239], + ['North', 'Amy', 'Grape', 6420], + ['South', 'Sal', 'Apple', 1310], + ['East', 'Fritz', 'Banana', 6274], + ['West', 'Sravan', 'Pear', 4894], + ['North', 'Xi', 'Grape', 7580], + ['South', 'Hector', 'Apple', 98144], + ]; + } + + protected function sampleDataForColumn(): array + { + return [ + ['Aiden', 'Andrew', 'Betty', 'Caden', 'Charlotte', 'Emma', 'Isabella', 'Mason', 'Oliver', 'Zoe'], + ['A', 'C', 'B', 'A', 'B', 'C', 'A', 'A', 'B', 'B'], + [0, 4, 1, 2, 2, 0, 2, 4, 4, 8], + ]; + } +} diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/MatrixHelperFunctionsTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/MatrixHelperFunctionsTest.php new file mode 100644 index 00000000..e5b4cace --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/LookupRef/MatrixHelperFunctionsTest.php @@ -0,0 +1,77 @@ +