-
Notifications
You must be signed in to change notification settings - Fork 3.5k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Correct Re-computation of Relative Addresses in Defined Names (#3673)
* Correct Re-computation of Relative Addresses in Defined Names Fix #3661. Insertion or deletion of rows or columns can cause changes to the ranges for Defined Names. In fact, only the absolute parts of such ranges should be adjusted, while the relative parts should be left alone. Otherwise, as the original issue documents, the adjustment to the relative portion winds up being double-counted when the Defined Name is referenced in a formula. The major part of this change is to ReferenceHelper and CellReferenceHelper to not adjust relative addresses for Defined Names. An additional small change is needed in the Calculation engine to `recursiveCalculationCell` when a Defined Formula is being calculated. In a sense, this is a breaking change, but for an obscure use case which (a) was wrong, and (b) is unlikely to be of importance. Some of the tests in ReferenceHelperTest were wrong and are now corrected, with the results being cross-checked against Excel. When a Defined Name using relative addressing is defined in Excel, the result is treated as relative to the active cell on the sheet in which the name is defined. PhpSpreadsheet treats it as relative to cell A1. I think that is a reasonable treatment, and will not change its behavior to match Excel's - that would definitely be a breaking change of some consequence. An interesting use of relative address in a defined name is demonstrated at https://excelguru.ca/always-refer-to-the-cell-above/. Note that the steps there involve setting the selected cell to A2 before defining the name. When that spreadsheet is stored, the actual definition of the range is `A1048576`. Likewise, adding a defined name for the cell to the left would be stored as `XFD1`. This seems a little fragile, but Ods, which I believe does not have the same row and column limits as Excel, certainly treats these values the same as Excel. This particular construction is formally unit-tested. Note, however, that although using these Defined Names as a formula on their own works just fine, a construction like `=SUM(A1:CellAbove)`, as suggested in the article, seems to put PhpSpreadsheet calculation engine in a loop. In the likely event that I can't solve that before I merge this change, I will open a new issue to that effect when I do merge it. Note that this can be handled without defined names as `=SUM(A$1:INDIRECT(ADDRESS(ROW()-1,COLUMN())))`. PhpSpreadsheet will handle this as a cell formula, but not yet as a Named Formula. The tests show a breakdown evaluating `=ProductTotal` (product of 2 formulas using defined names with relative addresses) on the sheet on which it is defined, but it works from a different sheet. The usual debugging techniques show me why this is happening, but I can't see how to overcome it. As above, if I can't solve it before I merge, I will open a new issue. For those situations where I intend to open a new issue, tests are added but are marked Incomplete. Because of those, I will leave this PR in draft status for 2 weeks before moving forward with it. * Fix productTotal Problem Need to restore current cell after evaluating defined name.
- Loading branch information
Showing
6 changed files
with
322 additions
and
61 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,113 @@ | ||
<?php | ||
|
||
namespace PhpOffice\PhpSpreadsheetTests; | ||
|
||
use PhpOffice\PhpSpreadsheet\Calculation\Calculation; | ||
use PhpOffice\PhpSpreadsheet\NamedRange; | ||
use PhpOffice\PhpSpreadsheet\Spreadsheet; | ||
use PHPUnit\Framework\TestCase; | ||
|
||
class ReferenceHelper3Test extends TestCase | ||
{ | ||
public function testIssue3661(): void | ||
{ | ||
$spreadsheet = new Spreadsheet(); | ||
$sheet = $spreadsheet->getActiveSheet(); | ||
$sheet->setTitle('Data'); | ||
|
||
$spreadsheet->addNamedRange(new NamedRange('FIRST', $sheet, '=$A1')); | ||
$spreadsheet->addNamedRange(new NamedRange('SECOND', $sheet, '=$B1')); | ||
$spreadsheet->addNamedRange(new NamedRange('THIRD', $sheet, '=$C1')); | ||
|
||
$sheet->fromArray([ | ||
[1, 2, 3, '=FIRST', '=SECOND', '=THIRD', '=10*$A1'], | ||
[4, 5, 6, '=FIRST', '=SECOND', '=THIRD'], | ||
[7, 8, 9, '=FIRST', '=SECOND', '=THIRD'], | ||
]); | ||
|
||
$sheet->insertNewRowBefore(1, 4); | ||
$sheet->insertNewColumnBefore('A', 1); | ||
self::assertSame(1, $sheet->getCell('E5')->getCalculatedValue()); | ||
self::assertSame(5, $sheet->getCell('F6')->getCalculatedValue()); | ||
self::assertSame(9, $sheet->getCell('G7')->getCalculatedValue()); | ||
self::assertSame('=10*$B5', $sheet->getCell('H5')->getValue()); | ||
self::assertSame(10, $sheet->getCell('H5')->getCalculatedValue()); | ||
$firstColumn = $spreadsheet->getNamedRange('FIRST'); | ||
/** @var NamedRange $firstColumn */ | ||
self::assertSame('=$B1', $firstColumn->getRange()); | ||
$spreadsheet->disconnectWorksheets(); | ||
} | ||
|
||
public function testCompletelyRelative(): void | ||
{ | ||
$spreadsheet = new Spreadsheet(); | ||
$sheet = $spreadsheet->getActiveSheet(); | ||
$sheet->setTitle('Data'); | ||
|
||
$spreadsheet->addNamedRange(new NamedRange('CellAbove', $sheet, '=A1048576')); | ||
$spreadsheet->addNamedRange(new NamedRange('CellBelow', $sheet, '=A2')); | ||
$spreadsheet->addNamedRange(new NamedRange('CellToLeft', $sheet, '=XFD1')); | ||
$spreadsheet->addNamedRange(new NamedRange('CellToRight', $sheet, '=B1')); | ||
|
||
$sheet->fromArray([ | ||
[null, 'Above', null, null, 'Above', null, null, 'Above', null, null, 'Above', null], | ||
['Left', '=CellAbove', 'Right', 'Left', '=CellBelow', 'Right', 'Left', '=CellToLeft', 'Right', 'Left', '=CellToRight', 'Right'], | ||
[null, 'Below', null, null, 'Below', null, null, 'Below', null, null, 'Below', null], | ||
], null, 'A1', true); | ||
self::assertSame('Above', $sheet->getCell('B2')->getCalculatedValue()); | ||
self::assertSame('Below', $sheet->getCell('E2')->getCalculatedValue()); | ||
self::assertSame('Left', $sheet->getCell('H2')->getCalculatedValue()); | ||
self::assertSame('Right', $sheet->getCell('K2')->getCalculatedValue()); | ||
|
||
Calculation::getInstance($spreadsheet)->flushInstance(); | ||
self::assertNull($sheet->getCell('L7')->getCalculatedValue(), 'value in L7 after flush is null'); | ||
// Reset it once more | ||
Calculation::getInstance($spreadsheet)->flushInstance(); | ||
// shift 5 rows down and 1 column to the right | ||
$sheet->insertNewRowBefore(1, 5); | ||
$sheet->insertNewColumnBefore('A', 1); | ||
|
||
self::assertSame('Above', $sheet->getCell('C7')->getCalculatedValue()); // Above | ||
self::assertSame('Below', $sheet->getCell('F7')->getCalculatedValue()); | ||
self::assertSame('Left', $sheet->getCell('I7')->getCalculatedValue()); | ||
self::assertSame('Right', $sheet->getCell('L7')->getCalculatedValue()); | ||
|
||
$sheet2 = $spreadsheet->createSheet(); | ||
$sheet2->setCellValue('L6', 'NotThisCell'); | ||
$sheet2->setCellValue('L7', '=CellAbove'); | ||
self::assertSame('Above', $sheet2->getCell('L7')->getCalculatedValue(), 'relative value uses cell on worksheet where name is defined'); | ||
$spreadsheet->disconnectWorksheets(); | ||
} | ||
|
||
/** @var bool */ | ||
private static $sumFormulaWorking = false; | ||
|
||
public function testSumAboveCell(): void | ||
{ | ||
$spreadsheet = new Spreadsheet(); | ||
$sheet = $spreadsheet->getActiveSheet(); | ||
$spreadsheet->addNamedRange(new NamedRange('AboveCell', $sheet, 'A1048576')); | ||
$sheet->setCellValue('C2', 123); | ||
$sheet->setCellValue('C3', '=AboveCell'); | ||
$sheet->fromArray([ | ||
['Column 1', 'Column 2'], | ||
[2, 1], | ||
[4, 3], | ||
[6, 5], | ||
[8, 7], | ||
[10, 9], | ||
[12, 11], | ||
[14, 13], | ||
[16, 15], | ||
['=SUM(A2:AboveCell)', '=SUM(B2:AboveCell)'], | ||
], null, 'A1', true); | ||
self::assertSame(123, $sheet->getCell('C3')->getCalculatedValue()); | ||
if (self::$sumFormulaWorking) { | ||
self::assertSame(72, $sheet->getCell('A10')->getCalculatedValue()); | ||
} else { | ||
$spreadsheet->disconnectWorksheets(); | ||
self::markTestIncomplete('PhpSpreadsheet does not handle this correctly'); | ||
} | ||
$spreadsheet->disconnectWorksheets(); | ||
} | ||
} |
Oops, something went wrong.