Skip to content

Commit

Permalink
MATCH with a static array should return the position of the found val…
Browse files Browse the repository at this point in the history
…ue based on the values submitted.

Returns #N/A, unless the element searched for is at the end of the array.

The problem is in Calculation.php line 4231:
                    if (!is_array($functionCall)) {
                        foreach ($args as &$arg) {
                            $arg = Functions::flattenSingleValue($arg);
                        }
                        unset($arg);
                    }

I believe this code is intended to handle functions where PhpSpreadsheet just passes
the call on to PHP without implementing the code on its own, e.g. for atan or acos.
In the bug report, the following code fails:
  $flat_rate = "=MATCH(6,{4,5,6,2}, 0)";
  $sheet->getCell('A1')->setValue($flat_rate);
The expected value is 3, but the actual result is "#N/A".
The reason for this result is that the parser replaces the braces with calls
to the MKMATRIX internal function, whose value for functioncall was:
'self::MKMATRIX'. Since this isn't an array, the flattening code is executed,
and the unintended result occurs. The fix is to change the definition for
functioncall in that case to [__CLASS__, 'mkMatrix'], avoiding the flattening.

However, there is also another part to this bug. The flattening should be
returning the first entry in the array, but is in fact returning the last.
This explains why the bug report specified "unless ... end of the array".
I confirmed that Excel does use the first item in the array rather than the last,
e.g. =atan({1,2,3}) entered into a cell will return atan(1), not atan(3).
The problem here is that flattenSingleValue, which says in its comments that
it is supposed to be returning the first item, uses array_pop rather than array_shift.
I have changed that as well. The same mistake was also present in
Cell.php function getCalculatedValue. The correct behavior can be verified
by entering =minverse({-2.5,1.5;2,-1}) into an Excel cell'
Excel flattens the result ({2,3;4,5}) to 2, and so should PhpSpreadsheet.

Fixes #1271
Closes #1332
  • Loading branch information
oleibman authored and PowerKiKi committed Apr 26, 2020
1 parent 6788869 commit c4895b9
Show file tree
Hide file tree
Showing 6 changed files with 74 additions and 3 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).
- Fix ROUNDUP and ROUNDDOWN for floating-point rounding error [#1404](https://github.com/PHPOffice/PhpSpreadsheet/pull/1404)
- Fix loading styles from vmlDrawings when containing whitespace [#1347](https://github.com/PHPOffice/PhpSpreadsheet/issues/1347)
- Fix incorrect behavior when removing last row [#1365](https://github.com/PHPOffice/PhpSpreadsheet/pull/1365)
- MATCH with a static array should return the position of the found value based on the values submitted [#1332](https://github.com/PHPOffice/PhpSpreadsheet/pull/1332)

## [1.11.0] - 2020-03-02

Expand Down
2 changes: 1 addition & 1 deletion src/PhpSpreadsheet/Calculation/Calculation.php
Original file line number Diff line number Diff line change
Expand Up @@ -2235,7 +2235,7 @@ class Calculation
private static $controlFunctions = [
'MKMATRIX' => [
'argumentCount' => '*',
'functionCall' => 'self::mkMatrix',
'functionCall' => [__CLASS__, 'mkMatrix'],
],
];

Expand Down
2 changes: 1 addition & 1 deletion src/PhpSpreadsheet/Calculation/Functions.php
Original file line number Diff line number Diff line change
Expand Up @@ -646,7 +646,7 @@ public static function flattenArrayIndexed($array)
public static function flattenSingleValue($value = '')
{
while (is_array($value)) {
$value = array_pop($value);
$value = array_shift($value);
}

return $value;
Expand Down
2 changes: 1 addition & 1 deletion src/PhpSpreadsheet/Cell/Cell.php
Original file line number Diff line number Diff line change
Expand Up @@ -266,7 +266,7 @@ public function getCalculatedValue($resetLog = true)
// We don't yet handle array returns
if (is_array($result)) {
while (is_array($result)) {
$result = array_pop($result);
$result = array_shift($result);
}
}
} catch (Exception $ex) {
Expand Down
46 changes: 46 additions & 0 deletions tests/PhpSpreadsheetTests/Calculation/FormulaAsStringTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
<?php

namespace PhpOffice\PhpSpreadsheetTests\Calculation;

use PhpOffice\PhpSpreadsheet\Spreadsheet;
use PHPUnit\Framework\TestCase;

class FormulaAsStringTest extends TestCase
{
/**
* @dataProvider providerFunctionsAsString
*
* @param mixed $expectedResult
* @param string $formula
*/
public function testFunctionsAsString($expectedResult, $formula)
{
$spreadsheet = new Spreadsheet();
$workSheet = $spreadsheet->getActiveSheet();
$workSheet->setCellValue('A1', 10);
$workSheet->setCellValue('A2', 20);
$workSheet->setCellValue('A3', 30);
$workSheet->setCellValue('A4', 40);
$spreadsheet->addNamedRange(new \PhpOffice\PhpSpreadsheet\NamedRange('namedCell', $workSheet, 'A4'));
$workSheet->setCellValue('B1', 'uPPER');
$workSheet->setCellValue('B2', '=TRUE()');
$workSheet->setCellValue('B3', '=FALSE()');

$ws2 = $spreadsheet->createSheet();
$ws2->setCellValue('A1', 100);
$ws2->setCellValue('A2', 200);
$ws2->setTitle('Sheet2');
$spreadsheet->addNamedRange(new \PhpOffice\PhpSpreadsheet\NamedRange('A2B', $ws2, 'A2'));

$spreadsheet->setActiveSheetIndex(0);
$cell2 = $workSheet->getCell('D1');
$cell2->setValue($formula);
$result = $cell2->getCalculatedValue();
self::assertEquals($expectedResult, $result);
}

public function providerFunctionsAsString()
{
return require 'data/Calculation/FunctionsAsString.php';
}
}
24 changes: 24 additions & 0 deletions tests/data/Calculation/FunctionsAsString.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
<?php

return [
// Note that these are meant to test the parser, not a comprehensive
// test of all Excel functions, which tests are handled elsewhere.
[6, '=SUM(1,2,3)'],
[60, '=SUM(A1:A3)'],
[70, '=SUM(A1,A2,A4)'],
[41, '=SUM(1,namedCell)'],
[50, '=A1+namedCell'],
[3, '=MATCH(6,{4,5,6,2},0)'],
['#N/A', '=MATCH(8,{4,5,6,2},0)'],
[7, '=HLOOKUP(5,{1,5,10;2,6,11;3,7,12;4,8,13},3,FALSE)'],
['Hello, World.', '=CONCATENATE("Hello, ", "World.")'],
['{NON-EMPTY SET}', '=UPPER("{non-EMPTY set}")'], // braces not used for matrix
['upper', '=LOWER(B1)'],
[false, '=and(B2,B3)'],
[0, '=acos(1)'],
[0.785398, '=round(atan({1,2,3}),6)'], // {1,2,3} will be flattened to 1
[2, '=minverse({-2.5,1.5;2,-1})'], // 2 is the flattened result of {2,3;4,5}
[4, '=MDETERM(MMULT({1,2;3,4},{5,6;7,8}))'], // multiple matrices
[110, '=SUM(A1,Sheet2!$A$1)'], // different sheet absolute address
[220, '=SUM(A2,A2B)'], // defined name on different sheet
];

0 comments on commit c4895b9

Please sign in to comment.