Skip to content

Commit 8d7be25

Browse files
author
Mark Baker
authored
Improve Range handling in the Calculation Engine for Row and Column ranges (#2028)
* Improve Range handling in the Calculation Engine for Row and Column ranges
1 parent 27eac4d commit 8d7be25

File tree

4 files changed

+160
-35
lines changed

4 files changed

+160
-35
lines changed

CHANGELOG.md

+1
Original file line numberDiff line numberDiff line change
@@ -9,6 +9,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).
99

1010
### Added
1111

12+
- Improved support for Row and Column ranges in formulae [Issue #1755](https://github.com/PHPOffice/PhpSpreadsheet/issues/1755) [PR #2028](https://github.com/PHPOffice/PhpSpreadsheet/pull/2028)
1213
- Implemented the CHITEST(), CHISQ.DIST() and CHISQ.INV() and equivalent Statistical functions, for both left- and right-tailed distributions.
1314
- Support for ActiveSheet and SelectedCells in the ODS Reader and Writer. [PR #1908](https://github.com/PHPOffice/PhpSpreadsheet/pull/1908)
1415

src/PhpSpreadsheet/Calculation/Calculation.php

+71-33
Original file line numberDiff line numberDiff line change
@@ -30,6 +30,9 @@ class Calculation
3030
const CALCULATION_REGEXP_CELLREF = '((([^\s,!&%^\/\*\+<>=-]*)|(\'[^\']*\')|(\"[^\"]*\"))!)?\$?\b([a-z]{1,3})\$?(\d{1,7})(?![\w.])';
3131
// Cell reference (with or without a sheet reference) ensuring absolute/relative
3232
const CALCULATION_REGEXP_CELLREF_RELATIVE = '((([^\s\(,!&%^\/\*\+<>=-]*)|(\'[^\']*\')|(\"[^\"]*\"))!)?(\$?\b[a-z]{1,3})(\$?\d{1,7})(?![\w.])';
33+
const CALCULATION_REGEXP_COLUMN_RANGE = '(((([^\s\(,!&%^\/\*\+<>=-]*)|(\'[^\']*\')|(\"[^\"]*\"))!)?(\$?[a-z]{1,3})):(?![.*])';
34+
const CALCULATION_REGEXP_ROW_RANGE = '(((([^\s\(,!&%^\/\*\+<>=-]*)|(\'[^\']*\')|(\"[^\"]*\"))!)?(\$?[1-9][0-9]{0,6})):(?![.*])';
35+
// Cell reference (with or without a sheet reference) ensuring absolute/relative
3336
// Cell ranges ensuring absolute/relative
3437
const CALCULATION_REGEXP_COLUMNRANGE_RELATIVE = '(\$?[a-z]{1,3}):(\$?[a-z]{1,3})';
3538
const CALCULATION_REGEXP_ROWRANGE_RELATIVE = '(\$?\d{1,7}):(\$?\d{1,7})';
@@ -3798,6 +3801,8 @@ private function internalParseFormula($formula, ?Cell $pCell = null)
37983801

37993802
$regexpMatchString = '/^(' . self::CALCULATION_REGEXP_FUNCTION .
38003803
'|' . self::CALCULATION_REGEXP_CELLREF .
3804+
'|' . self::CALCULATION_REGEXP_COLUMN_RANGE .
3805+
'|' . self::CALCULATION_REGEXP_ROW_RANGE .
38013806
'|' . self::CALCULATION_REGEXP_NUMBER .
38023807
'|' . self::CALCULATION_REGEXP_STRING .
38033808
'|' . self::CALCULATION_REGEXP_OPENBRACE .
@@ -3866,7 +3871,8 @@ private function internalParseFormula($formula, ?Cell $pCell = null)
38663871
$opCharacter .= $formula[++$index];
38673872
}
38683873
// Find out if we're currently at the beginning of a number, variable, cell reference, function, parenthesis or operand
3869-
$isOperandOrFunction = preg_match($regexpMatchString, substr($formula, $index), $match);
3874+
$isOperandOrFunction = (bool) preg_match($regexpMatchString, substr($formula, $index), $match);
3875+
38703876
if ($opCharacter == '-' && !$expectingOperator) { // Is it a negation instead of a minus?
38713877
// Put a negation on the stack
38723878
$stack->push('Unary Operator', '~', null, $currentCondition, $currentOnlyIf, $currentOnlyIfNot);
@@ -4038,6 +4044,7 @@ private function internalParseFormula($formula, ?Cell $pCell = null)
40384044
$expectingOperand = false;
40394045
$val = $match[1];
40404046
$length = strlen($val);
4047+
40414048
if (preg_match('/^' . self::CALCULATION_REGEXP_FUNCTION . '$/miu', $val, $matches)) {
40424049
$val = preg_replace('/\s/u', '', $val);
40434050
if (isset(self::$phpSpreadsheetFunctions[strtoupper($matches[1])]) || isset(self::$controlFunctions[strtoupper($matches[1])])) { // it's a function
@@ -4074,7 +4081,7 @@ private function internalParseFormula($formula, ?Cell $pCell = null)
40744081
// Should only be applied to the actual cell column, not the worksheet name
40754082
// If the last entry on the stack was a : operator, then we have a cell range reference
40764083
$testPrevOp = $stack->last(1);
4077-
if ($testPrevOp !== null && $testPrevOp['value'] == ':') {
4084+
if ($testPrevOp !== null && $testPrevOp['value'] === ':') {
40784085
// If we have a worksheet reference, then we're playing with a 3D reference
40794086
if ($matches[2] == '') {
40804087
// Otherwise, we 'inherit' the worksheet reference from the start cell reference
@@ -4091,73 +4098,99 @@ private function internalParseFormula($formula, ?Cell $pCell = null)
40914098
return $this->raiseFormulaError('3D Range references are not yet supported');
40924099
}
40934100
}
4101+
} elseif (strpos($val, '!') === false && $pCellParent !== null) {
4102+
$worksheet = $pCellParent->getTitle();
4103+
$val = "'{$worksheet}'!{$val}";
40944104
}
40954105

40964106
$outputItem = $stack->getStackItem('Cell Reference', $val, $val, $currentCondition, $currentOnlyIf, $currentOnlyIfNot);
40974107

40984108
$output[] = $outputItem;
40994109
} else { // it's a variable, constant, string, number or boolean
4110+
$localeConstant = false;
4111+
$stackItemType = 'Value';
4112+
$stackItemReference = null;
4113+
41004114
// If the last entry on the stack was a : operator, then we may have a row or column range reference
41014115
$testPrevOp = $stack->last(1);
41024116
if ($testPrevOp !== null && $testPrevOp['value'] === ':') {
4117+
$stackItemType = 'Cell Reference';
41034118
$startRowColRef = $output[count($output) - 1]['value'];
41044119
[$rangeWS1, $startRowColRef] = Worksheet::extractSheetTitle($startRowColRef, true);
41054120
$rangeSheetRef = $rangeWS1;
4106-
if ($rangeWS1 != '') {
4121+
if ($rangeWS1 !== '') {
41074122
$rangeWS1 .= '!';
41084123
}
4124+
$rangeSheetRef = trim($rangeSheetRef, "'");
41094125
[$rangeWS2, $val] = Worksheet::extractSheetTitle($val, true);
4110-
if ($rangeWS2 != '') {
4126+
if ($rangeWS2 !== '') {
41114127
$rangeWS2 .= '!';
41124128
} else {
41134129
$rangeWS2 = $rangeWS1;
41144130
}
4131+
41154132
$refSheet = $pCellParent;
4116-
if ($pCellParent !== null && $rangeSheetRef !== $pCellParent->getTitle()) {
4133+
if ($pCellParent !== null && $rangeSheetRef !== '' && $rangeSheetRef !== $pCellParent->getTitle()) {
41174134
$refSheet = $pCellParent->getParent()->getSheetByName($rangeSheetRef);
41184135
}
4119-
if (
4120-
(is_int($startRowColRef)) && (ctype_digit($val)) &&
4121-
($startRowColRef <= 1048576) && ($val <= 1048576)
4122-
) {
4136+
4137+
if (ctype_digit($val) && $val <= 1048576) {
41234138
// Row range
4124-
$endRowColRef = ($refSheet !== null) ? $refSheet->getHighestColumn() : 'XFD'; // Max 16,384 columns for Excel2007
4125-
$output[count($output) - 1]['value'] = $rangeWS1 . 'A' . $startRowColRef;
4126-
$val = $rangeWS2 . $endRowColRef . $val;
4127-
} elseif (
4128-
(ctype_alpha($startRowColRef)) && (ctype_alpha($val)) &&
4129-
(strlen($startRowColRef) <= 3) && (strlen($val) <= 3)
4130-
) {
4139+
$stackItemType = 'Row Reference';
4140+
$endRowColRef = ($refSheet !== null) ? $refSheet->getHighestDataColumn($val) : 'XFD'; // Max 16,384 columns for Excel2007
4141+
$val = "{$rangeWS2}{$endRowColRef}{$val}";
4142+
} elseif (ctype_alpha($val) && strlen($val) <= 3) {
41314143
// Column range
4132-
$endRowColRef = ($refSheet !== null) ? $refSheet->getHighestRow() : 1048576; // Max 1,048,576 rows for Excel2007
4133-
$output[count($output) - 1]['value'] = $rangeWS1 . strtoupper($startRowColRef) . '1';
4134-
$val = $rangeWS2 . $val . $endRowColRef;
4144+
$stackItemType = 'Column Reference';
4145+
$endRowColRef = ($refSheet !== null) ? $refSheet->getHighestDataRow($val) : 1048576; // Max 1,048,576 rows for Excel2007
4146+
$val = "{$rangeWS2}{$val}{$endRowColRef}";
41354147
}
4136-
}
4137-
4138-
$localeConstant = false;
4139-
$stackItemType = 'Value';
4140-
$stackItemReference = null;
4141-
if ($opCharacter == self::FORMULA_STRING_QUOTE) {
4148+
$stackItemReference = $val;
4149+
} elseif ($opCharacter == self::FORMULA_STRING_QUOTE) {
41424150
// UnEscape any quotes within the string
41434151
$val = self::wrapResult(str_replace('""', self::FORMULA_STRING_QUOTE, self::unwrapResult($val)));
4144-
} elseif (is_numeric($val)) {
4145-
if ((strpos($val, '.') !== false) || (stripos($val, 'e') !== false) || ($val > PHP_INT_MAX) || ($val < -PHP_INT_MAX)) {
4146-
$val = (float) $val;
4147-
} else {
4148-
$val = (int) $val;
4149-
}
41504152
} elseif (isset(self::$excelConstants[trim(strtoupper($val))])) {
41514153
$stackItemType = 'Constant';
41524154
$excelConstant = trim(strtoupper($val));
41534155
$val = self::$excelConstants[$excelConstant];
41544156
} elseif (($localeConstant = array_search(trim(strtoupper($val)), self::$localeBoolean)) !== false) {
41554157
$stackItemType = 'Constant';
41564158
$val = self::$excelConstants[$localeConstant];
4159+
} elseif (
4160+
preg_match('/^' . self::CALCULATION_REGEXP_ROW_RANGE . '/miu', substr($formula, $index), $rowRangeReference)
4161+
) {
4162+
$val = $rowRangeReference[1];
4163+
$length = strlen($rowRangeReference[1]);
4164+
$stackItemType = 'Row Reference';
4165+
$column = 'A';
4166+
if (($testPrevOp !== null && $testPrevOp['value'] === ':') && $pCellParent !== null) {
4167+
$column = $pCellParent->getHighestDataColumn($val);
4168+
}
4169+
$val = "{$rowRangeReference[2]}{$column}{$rowRangeReference[7]}";
4170+
$stackItemReference = $val;
4171+
} elseif (
4172+
preg_match('/^' . self::CALCULATION_REGEXP_COLUMN_RANGE . '/miu', substr($formula, $index), $columnRangeReference)
4173+
) {
4174+
$val = $columnRangeReference[1];
4175+
$length = strlen($val);
4176+
$stackItemType = 'Column Reference';
4177+
$row = '1';
4178+
if (($testPrevOp !== null && $testPrevOp['value'] === ':') && $pCellParent !== null) {
4179+
$row = $pCellParent->getHighestDataRow($val);
4180+
}
4181+
$val = "{$val}{$row}";
4182+
$stackItemReference = $val;
41574183
} elseif (preg_match('/^' . self::CALCULATION_REGEXP_DEFINEDNAME . '.*/miu', $val, $match)) {
41584184
$stackItemType = 'Defined Name';
41594185
$stackItemReference = $val;
4186+
} elseif (is_numeric($val)) {
4187+
if ((strpos($val, '.') !== false) || (stripos($val, 'e') !== false) || ($val > PHP_INT_MAX) || ($val < -PHP_INT_MAX)) {
4188+
$val = (float) $val;
4189+
} else {
4190+
$val = (int) $val;
4191+
}
41604192
}
4193+
41614194
$details = $stack->getStackItem($stackItemType, $val, $stackItemReference, $currentCondition, $currentOnlyIf, $currentOnlyIfNot);
41624195
if ($localeConstant) {
41634196
$details['localeValue'] = $localeConstant;
@@ -4431,6 +4464,7 @@ private function processTokenStack($tokens, $cellID = null, ?Cell $pCell = null)
44314464
} else {
44324465
return $this->raiseFormulaError('Unable to access Cell Reference');
44334466
}
4467+
44344468
$stack->push('Cell Reference', $cellValue, $cellRef);
44354469
} else {
44364470
$stack->push('Error', Functions::REF(), null);
@@ -4564,6 +4598,7 @@ private function processTokenStack($tokens, $cellID = null, ?Cell $pCell = null)
45644598
}
45654599
} elseif (preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/i', $token, $matches)) {
45664600
$cellRef = null;
4601+
45674602
if (isset($matches[8])) {
45684603
if ($pCell === null) {
45694604
// We can't access the range, so return a REF error
@@ -4596,7 +4631,7 @@ private function processTokenStack($tokens, $cellID = null, ?Cell $pCell = null)
45964631
}
45974632
} else {
45984633
if ($pCell === null) {
4599-
// We can't access the cell, so return a REF error
4634+
// We can't access the cell, so return a REF error
46004635
$cellValue = Functions::REF();
46014636
} else {
46024637
$cellRef = $matches[6] . $matches[7];
@@ -4613,6 +4648,7 @@ private function processTokenStack($tokens, $cellID = null, ?Cell $pCell = null)
46134648
$cellValue = $this->extractCellRange($cellRef, $this->spreadsheet->getSheetByName($matches[2]), false);
46144649
$pCell->attach($pCellParent);
46154650
} else {
4651+
$cellRef = ($cellSheet !== null) ? "{$matches[2]}!{$cellRef}" : $cellRef;
46164652
$cellValue = null;
46174653
}
46184654
} else {
@@ -4631,7 +4667,8 @@ private function processTokenStack($tokens, $cellID = null, ?Cell $pCell = null)
46314667
}
46324668
}
46334669
}
4634-
$stack->push('Value', $cellValue, $cellRef);
4670+
4671+
$stack->push('Cell Value', $cellValue, $cellRef);
46354672
if (isset($storeKey)) {
46364673
$branchStore[$storeKey] = $cellValue;
46374674
}
@@ -5116,6 +5153,7 @@ public function extractCellRange(&$pRange = 'A1', ?Worksheet $pSheet = null, $re
51165153

51175154
if ($pSheet !== null) {
51185155
$pSheetName = $pSheet->getTitle();
5156+
51195157
if (strpos($pRange, '!') !== false) {
51205158
[$pSheetName, $pRange] = Worksheet::extractSheetTitle($pRange, true);
51215159
$pSheet = $this->spreadsheet->getSheetByName($pSheetName);

src/PhpSpreadsheet/Calculation/MathTrig/Sum.php

+4-2
Original file line numberDiff line numberDiff line change
@@ -50,11 +50,13 @@ public static function funcSum(...$args)
5050
public static function funcSumNoStrings(...$args)
5151
{
5252
$returnValue = 0;
53-
5453
// Loop through the arguments
5554
foreach (Functions::flattenArray($args) as $arg) {
5655
// Is it a numeric value?
57-
if (is_numeric($arg)) {
56+
if (is_numeric($arg) || empty($arg)) {
57+
if (is_string($arg)) {
58+
$arg = (int) $arg;
59+
}
5860
$returnValue += $arg;
5961
} elseif (Functions::isError($arg)) {
6062
return $arg;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,84 @@
1+
<?php
2+
3+
namespace PhpOffice\PhpSpreadsheetTests\Calculation;
4+
5+
use PhpOffice\PhpSpreadsheet\Spreadsheet;
6+
use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet;
7+
use PHPUnit\Framework\TestCase;
8+
9+
class RowColumnReferenceTest extends TestCase
10+
{
11+
/**
12+
* @var Spreadsheet
13+
*/
14+
protected $spreadSheet;
15+
16+
protected function setUp(): void
17+
{
18+
$this->spreadSheet = new Spreadsheet();
19+
20+
$dataSheet = new Worksheet($this->spreadSheet, 'data sheet');
21+
$this->spreadSheet->addSheet($dataSheet, 0);
22+
$dataSheet->setCellValue('B1', 1.1);
23+
$dataSheet->setCellValue('B2', 2.2);
24+
$dataSheet->setCellValue('B3', 4.4);
25+
$dataSheet->setCellValue('C3', 8.8);
26+
$dataSheet->setCellValue('D3', 16.16);
27+
28+
$calcSheet = new Worksheet($this->spreadSheet, 'summary sheet');
29+
$this->spreadSheet->addSheet($calcSheet, 1);
30+
$calcSheet->setCellValue('B1', 2.2);
31+
$calcSheet->setCellValue('B2', 4.4);
32+
$calcSheet->setCellValue('B3', 8.8);
33+
$calcSheet->setCellValue('C3', 16.16);
34+
$calcSheet->setCellValue('D3', 32.32);
35+
36+
$this->spreadSheet->setActiveSheetIndexByName('summary sheet');
37+
}
38+
39+
/**
40+
* @dataProvider providerCurrentWorksheetFormulae
41+
*/
42+
public function testCurrentWorksheet(string $formula, float $expectedResult): void
43+
{
44+
$worksheet = $this->spreadSheet->getActiveSheet();
45+
46+
$worksheet->setCellValue('A1', $formula);
47+
48+
$result = $worksheet->getCell('A1')->getCalculatedValue();
49+
self::assertSame($expectedResult, $result);
50+
}
51+
52+
public function providerCurrentWorksheetFormulae(): array
53+
{
54+
return [
55+
'relative range in active worksheet' => ['=SUM(B1:B3)', 15.4],
56+
'range with absolute columns in active worksheet' => ['=SUM($B1:$B3)', 15.4],
57+
'range with absolute rows in active worksheet' => ['=SUM(B$1:B$3)', 15.4],
58+
'range with absolute columns and rows in active worksheet' => ['=SUM($B$1:$B$3)', 15.4],
59+
'another relative range in active worksheet' => ['=SUM(B3:D3)', 57.28],
60+
'relative column range in active worksheet' => ['=SUM(B:B)', 15.4],
61+
'absolute column range in active worksheet' => ['=SUM($B:$B)', 15.4],
62+
'relative row range in active worksheet' => ['=SUM(3:3)', 57.28],
63+
'absolute row range in active worksheet' => ['=SUM($3:$3)', 57.28],
64+
'relative range in specified active worksheet' => ['=SUM(\'summary sheet\'!B1:B3)', 15.4],
65+
'range with absolute columns in specified active worksheet' => ['=SUM(\'summary sheet\'!$B1:$B3)', 15.4],
66+
'range with absolute rows in specified active worksheet' => ['=SUM(\'summary sheet\'!B$1:B$3)', 15.4],
67+
'range with absolute columns and rows in specified active worksheet' => ['=SUM(\'summary sheet\'!$B$1:$B$3)', 15.4],
68+
'another relative range in specified active worksheet' => ['=SUM(\'summary sheet\'!B3:D3)', 57.28],
69+
'relative column range in specified active worksheet' => ['=SUM(\'summary sheet\'!B:B)', 15.4],
70+
'absolute column range in specified active worksheet' => ['=SUM(\'summary sheet\'!$B:$B)', 15.4],
71+
'relative row range in specified active worksheet' => ['=SUM(\'summary sheet\'!3:3)', 57.28],
72+
'absolute row range in specified active worksheet' => ['=SUM(\'summary sheet\'!$3:$3)', 57.28],
73+
'relative range in specified other worksheet' => ['=SUM(\'data sheet\'!B1:B3)', 7.7],
74+
'range with absolute columns in specified other worksheet' => ['=SUM(\'data sheet\'!$B1:$B3)', 7.7],
75+
'range with absolute rows in specified other worksheet' => ['=SUM(\'data sheet\'!B$1:B$3)', 7.7],
76+
'range with absolute columns and rows in specified other worksheet' => ['=SUM(\'data sheet\'!$B$1:$B$3)', 7.7],
77+
'another relative range in specified other worksheet' => ['=SUM(\'data sheet\'!B3:D3)', 29.36],
78+
'relative column range in specified other worksheet' => ['=SUM(\'data sheet\'!B:B)', 7.7],
79+
'absolute column range in specified other worksheet' => ['=SUM(\'data sheet\'!$B:$B)', 7.7],
80+
'relative row range in specified other worksheet' => ['=SUM(\'data sheet\'!3:3)', 29.36],
81+
'absolute row range in specified other worksheet' => ['=SUM(\'data sheet\'!$3:$3)', 29.36],
82+
];
83+
}
84+
}

0 commit comments

Comments
 (0)