Handle defined names with the range operator.
It gets awkward when the defined name is for an actual range rather than for an individual named cell; because we need to manipulate the stack when that happens. The code is ugly, and this is a rather simplistic approach, but it works as long as the named range is a cell, a cell range, or even a "chained" range - it won't work if we have union or intersection operators in the defined range - but it does provide formula support that never existed before.
This commit is contained in:
parent
8c84ce4399
commit
40730c6023
|
|
@ -66,6 +66,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).
|
||||||
|
|
||||||
### Fixed
|
### Fixed
|
||||||
|
|
||||||
|
- Support for "chained" ranges (e.g. `A5:C10:C20:F1`) in the Calculation Engine; and also support for using named ranges with the Range operator (e.g. `NamedRange1:NamedRange2`) [Issue #2730](https://github.com/PHPOffice/PhpSpreadsheet/issues/2730) [PR #2746](https://github.com/PHPOffice/PhpSpreadsheet/pull/2746)
|
||||||
- Update Conditional Formatting ranges and rule conditions when inserting/deleting rows/columns [Issue #2678](https://github.com/PHPOffice/PhpSpreadsheet/issues/2678) [PR #2689](https://github.com/PHPOffice/PhpSpreadsheet/pull/2689)
|
- Update Conditional Formatting ranges and rule conditions when inserting/deleting rows/columns [Issue #2678](https://github.com/PHPOffice/PhpSpreadsheet/issues/2678) [PR #2689](https://github.com/PHPOffice/PhpSpreadsheet/pull/2689)
|
||||||
- Allow `INDIRECT()` to accept row/column ranges as well as cell ranges [PR #2687](https://github.com/PHPOffice/PhpSpreadsheet/pull/2687)
|
- Allow `INDIRECT()` to accept row/column ranges as well as cell ranges [PR #2687](https://github.com/PHPOffice/PhpSpreadsheet/pull/2687)
|
||||||
- Fix bug when deleting cells with hyperlinks, where the hyperlink was then being "inherited" by whatever cell moved to that cell address.
|
- Fix bug when deleting cells with hyperlinks, where the hyperlink was then being "inherited" by whatever cell moved to that cell address.
|
||||||
|
|
|
||||||
|
|
@ -4176,6 +4176,28 @@ class Calculation
|
||||||
$testPrevOp = $stack->last(1);
|
$testPrevOp = $stack->last(1);
|
||||||
if ($testPrevOp !== null && $testPrevOp['value'] === ':') {
|
if ($testPrevOp !== null && $testPrevOp['value'] === ':') {
|
||||||
$stackItemType = 'Cell Reference';
|
$stackItemType = 'Cell Reference';
|
||||||
|
if (
|
||||||
|
(preg_match('/^' . self::CALCULATION_REGEXP_DEFINEDNAME . '$/mui', $val) !== false) &&
|
||||||
|
($this->spreadsheet->getNamedRange($val) !== null)
|
||||||
|
) {
|
||||||
|
$namedRange = $this->spreadsheet->getNamedRange($val);
|
||||||
|
if ($namedRange !== null) {
|
||||||
|
$stackItemType = 'Defined Name';
|
||||||
|
$address = str_replace('$', '', $namedRange->getValue());
|
||||||
|
$stackItemReference = $val;
|
||||||
|
if (strpos($address, ':') !== false) {
|
||||||
|
// We'll need to manipulate the stack for an actual named range rather than a named cell
|
||||||
|
$fromTo = explode(':', $address);
|
||||||
|
$to = array_pop($fromTo);
|
||||||
|
foreach ($fromTo as $from) {
|
||||||
|
$output[] = $stack->getStackItem($stackItemType, $from, $stackItemReference);
|
||||||
|
$output[] = $stack->getStackItem('Binary Operator', ':');
|
||||||
|
}
|
||||||
|
$address = $to;
|
||||||
|
}
|
||||||
|
$val = $address;
|
||||||
|
}
|
||||||
|
} else {
|
||||||
$startRowColRef = $output[count($output) - 1]['value'];
|
$startRowColRef = $output[count($output) - 1]['value'];
|
||||||
[$rangeWS1, $startRowColRef] = Worksheet::extractSheetTitle($startRowColRef, true);
|
[$rangeWS1, $startRowColRef] = Worksheet::extractSheetTitle($startRowColRef, true);
|
||||||
$rangeSheetRef = $rangeWS1;
|
$rangeSheetRef = $rangeWS1;
|
||||||
|
|
@ -4209,6 +4231,7 @@ class Calculation
|
||||||
$val = "{$rangeWS2}{$val}{$endRowColRef}";
|
$val = "{$rangeWS2}{$val}{$endRowColRef}";
|
||||||
}
|
}
|
||||||
$stackItemReference = $val;
|
$stackItemReference = $val;
|
||||||
|
}
|
||||||
} elseif ($opCharacter == self::FORMULA_STRING_QUOTE) {
|
} elseif ($opCharacter == self::FORMULA_STRING_QUOTE) {
|
||||||
// UnEscape any quotes within the string
|
// UnEscape any quotes within the string
|
||||||
$val = self::wrapResult(str_replace('""', self::FORMULA_STRING_QUOTE, self::unwrapResult($val)));
|
$val = self::wrapResult(str_replace('""', self::FORMULA_STRING_QUOTE, self::unwrapResult($val)));
|
||||||
|
|
@ -4484,6 +4507,14 @@ class Calculation
|
||||||
break;
|
break;
|
||||||
// Binary Operators
|
// Binary Operators
|
||||||
case ':': // Range
|
case ':': // Range
|
||||||
|
if ($operand1Data['type'] === 'Defined Name') {
|
||||||
|
if (preg_match('/$' . self::CALCULATION_REGEXP_DEFINEDNAME . '^/mui', $operand1Data['reference']) !== false) {
|
||||||
|
$definedName = $this->spreadsheet->getNamedRange($operand1Data['reference']);
|
||||||
|
if ($definedName !== null) {
|
||||||
|
$operand1Data['reference'] = $operand1Data['value'] = str_replace('$', '', $definedName->getValue());
|
||||||
|
}
|
||||||
|
}
|
||||||
|
}
|
||||||
if (strpos($operand1Data['reference'], '!') !== false) {
|
if (strpos($operand1Data['reference'], '!') !== false) {
|
||||||
[$sheet1, $operand1Data['reference']] = Worksheet::extractSheetTitle($operand1Data['reference'], true);
|
[$sheet1, $operand1Data['reference']] = Worksheet::extractSheetTitle($operand1Data['reference'], true);
|
||||||
} else {
|
} else {
|
||||||
|
|
|
||||||
|
|
@ -80,31 +80,35 @@ class RangeTest extends TestCase
|
||||||
/**
|
/**
|
||||||
* @dataProvider providerNamedRangeEvaluation
|
* @dataProvider providerNamedRangeEvaluation
|
||||||
*/
|
*/
|
||||||
public function testNamedRangeEvaluation(string $group1, string $group2, string $formula, int $expectedResult): void
|
public function testNamedRangeEvaluation(array $ranges, string $formula, int $expectedResult): void
|
||||||
{
|
{
|
||||||
$workSheet = $this->spreadSheet->getActiveSheet();
|
$workSheet = $this->spreadSheet->getActiveSheet();
|
||||||
$this->spreadSheet->addNamedRange(new NamedRange('GROUP1', $workSheet, $group1));
|
foreach ($ranges as $id => $range) {
|
||||||
$this->spreadSheet->addNamedRange(new NamedRange('GROUP2', $workSheet, $group2));
|
$this->spreadSheet->addNamedRange(new NamedRange('GROUP' . ++$id, $workSheet, $range));
|
||||||
|
}
|
||||||
|
|
||||||
$workSheet->setCellValue('E1', $formula);
|
$workSheet->setCellValue('H1', $formula);
|
||||||
|
|
||||||
$sumRresult = $workSheet->getCell('E1')->getCalculatedValue();
|
$sumRresult = $workSheet->getCell('H1')->getCalculatedValue();
|
||||||
self::assertSame($expectedResult, $sumRresult);
|
self::assertSame($expectedResult, $sumRresult);
|
||||||
}
|
}
|
||||||
|
|
||||||
public function providerNamedRangeEvaluation(): array
|
public function providerNamedRangeEvaluation(): array
|
||||||
{
|
{
|
||||||
return[
|
return[
|
||||||
['$A$1:$B$3', '$A$1:$C$2', '=SUM(GROUP1,GROUP2)', 75],
|
[['$A$1:$B$3', '$A$1:$C$2'], '=SUM(GROUP1,GROUP2)', 75],
|
||||||
['$A$1:$B$3', '$A$1:$C$2', '=COUNT(GROUP1,GROUP2)', 12],
|
[['$A$1:$B$3', '$A$1:$C$2'], '=COUNT(GROUP1,GROUP2)', 12],
|
||||||
['$A$1:$B$3', '$A$1:$C$2', '=SUM(GROUP1 GROUP2)', 18],
|
[['$A$1:$B$3', '$A$1:$C$2'], '=SUM(GROUP1 GROUP2)', 18],
|
||||||
['$A$1:$B$3', '$A$1:$C$2', '=COUNT(GROUP1 GROUP2)', 4],
|
[['$A$1:$B$3', '$A$1:$C$2'], '=COUNT(GROUP1 GROUP2)', 4],
|
||||||
['$A$1:$B$2', '$B$2:$C$3', '=SUM(GROUP1,GROUP2)', 64],
|
[['$A$1:$B$2', '$B$2:$C$3'], '=SUM(GROUP1,GROUP2)', 64],
|
||||||
['$A$1:$B$2', '$B$2:$C$3', '=COUNT(GROUP1,GROUP2)', 8],
|
[['$A$1:$B$2', '$B$2:$C$3'], '=COUNT(GROUP1,GROUP2)', 8],
|
||||||
['$A$1:$B$2', '$B$2:$C$3', '=SUM(GROUP1 GROUP2)', 8],
|
[['$A$1:$B$2', '$B$2:$C$3'], '=SUM(GROUP1 GROUP2)', 8],
|
||||||
['$A$1:$B$2', '$B$2:$C$3', '=COUNT(GROUP1 GROUP2)', 1],
|
[['$A$1:$B$2', '$B$2:$C$3'], '=COUNT(GROUP1 GROUP2)', 1],
|
||||||
['Worksheet!$A$1:$B$2', 'Worksheet!$B$2:$C$3', '=SUM(GROUP1,GROUP2)', 64],
|
[['$A$5', '$C$10:$C$20', '$F$1'], '=SUM(GROUP1:GROUP2:GROUP3)', 7260],
|
||||||
['Worksheet!$A$1:Worksheet!$B$2', 'Worksheet!$B$2:Worksheet!$C$3', '=SUM(GROUP1,GROUP2)', 64],
|
[['$A$5:$A$7', '$C$20', '$F$1'], '=SUM(GROUP1:GROUP2:GROUP3)', 7260],
|
||||||
|
[['$A$5:$A$7', '$C$10:$C$20', '$F$1'], '=SUM(GROUP1:GROUP2:GROUP3)', 7260],
|
||||||
|
[['Worksheet!$A$1:$B$2', 'Worksheet!$B$2:$C$3'], '=SUM(GROUP1,GROUP2)', 64],
|
||||||
|
[['Worksheet!$A$1:Worksheet!$B$2', 'Worksheet!$B$2:Worksheet!$C$3'], '=SUM(GROUP1,GROUP2)', 64],
|
||||||
];
|
];
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
|
||||||
Loading…
Reference in New Issue