Skip to content

Commit

Permalink
OFFSET should allow omitted height and width
Browse files Browse the repository at this point in the history
Commit 8dddf56 inadvertently removed the ability to omit the width
and height arguments to the OFFSET function. And #REF! is returned
because the function is validating that the new $pCell argument
is present. It is present, but it has been passed in the $height position.

We fixed this by always passing $pCell at the last position and filling
missing arguments with NULL values.

Fixes #561
Fixes #565
  • Loading branch information
PowerKiKi committed Oct 21, 2018
1 parent 7b362bd commit 09eb05f
Show file tree
Hide file tree
Showing 3 changed files with 53 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](http://semver.org/).
- Sheet title can contain exclamation mark - [#325](https://github.com/PHPOffice/PhpSpreadsheet/issues/325)
- Xls file cause the exception during open by Xls reader - [#402](https://github.com/PHPOffice/PhpSpreadsheet/issues/402)
- Skip non numeric value in SUMIF - [#618](https://github.com/PHPOffice/PhpSpreadsheet/pull/618)
- OFFSET should allow omitted height and width - [#561](https://github.com/PHPOffice/PhpSpreadsheet/issues/561)

## [1.4.1] - 2018-09-30

Expand Down
32 changes: 29 additions & 3 deletions src/PhpSpreadsheet/Calculation/Calculation.php
Original file line number Diff line number Diff line change
Expand Up @@ -3942,9 +3942,7 @@ private function processTokenStack($tokens, $cellID = null, Cell $pCell = null)
}

// Process the argument with the appropriate function call
if ($passCellReference) {
$args[] = $pCell;
}
$args = $this->addCellReference($args, $passCellReference, $pCell, $functionCall);

if (!is_array($functionCall)) {
foreach ($args as &$arg) {
Expand Down Expand Up @@ -4436,4 +4434,32 @@ public function getImplementedFunctionNames()

return $returnValue;
}

/**
* Add cell reference if needed while making sure that it is the last argument.
*
* @param array $args
* @param bool $passCellReference
* @param Cell $pCell
* @param array $functionCall
*
* @return array
*/
private function addCellReference(array $args, $passCellReference, Cell $pCell, array $functionCall)
{
if ($passCellReference) {
$className = $functionCall[0];
$methodName = $functionCall[1];

$reflectionMethod = new \ReflectionMethod($className, $methodName);
$argumentCount = count($reflectionMethod->getParameters());
while (count($args) < $argumentCount - 1) {
$args[] = null;
}

$args[] = $pCell;
}

return $args;
}
}
23 changes: 23 additions & 0 deletions tests/PhpSpreadsheetTests/Calculation/CalculationTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@

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

class CalculationTest extends TestCase
Expand Down Expand Up @@ -117,4 +118,26 @@ public function testDoesHandleXlfnFunctions()
$function = $tree[4];
self::assertEquals('Function', $function['type']);
}

public function testFormulaWithOptionalArgumentsAndRequiredCellReferenceShouldPassNullForMissingArguments()
{
$spreadsheet = new Spreadsheet();
$sheet = $spreadsheet->getActiveSheet();

$sheet->fromArray(
[
[1, 2, 3],
[4, 5, 6],
[7, 8, 9],
]
);

$cell = $sheet->getCell('E5');
$cell->setValue('=OFFSET(D3, -1, -2, 1, 1)');
self::assertEquals(5, $cell->getCalculatedValue(), 'with all arguments');

$cell = $sheet->getCell('F6');
$cell->setValue('=OFFSET(D3, -1, -2)');
self::assertEquals(5, $cell->getCalculatedValue(), 'missing arguments should be filled with null');
}
}

0 comments on commit 09eb05f

Please sign in to comment.