diff --git a/CHANGELOG.md b/CHANGELOG.md index 5c81a661..19995524 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -9,12 +9,12 @@ and this project adheres to [Semantic Versioning](https://semver.org). ### Added -- Nothing +- Implementation of the ISREF() information function ### Changed - Nothing -- + ### Deprecated - All Excel Function implementations in `Calculation\Functions` (including the Error functions) have been moved to dedicated classes for groups of related functions. See the docblocks against all the deprecated methods for details of the new methods to call instead. At some point, these old classes will be deleted. diff --git a/src/PhpSpreadsheet/Calculation/Calculation.php b/src/PhpSpreadsheet/Calculation/Calculation.php index 8ba77d3b..0f8c1b97 100644 --- a/src/PhpSpreadsheet/Calculation/Calculation.php +++ b/src/PhpSpreadsheet/Calculation/Calculation.php @@ -1526,8 +1526,10 @@ class Calculation ], 'ISREF' => [ 'category' => Category::CATEGORY_INFORMATION, - 'functionCall' => [Functions::class, 'DUMMY'], + 'functionCall' => [Information\Value::class, 'isRef'], 'argumentCount' => '1', + 'passCellReference' => true, + 'passByReference' => [true], ], 'ISTEXT' => [ 'category' => Category::CATEGORY_INFORMATION, diff --git a/src/PhpSpreadsheet/Calculation/Information/Value.php b/src/PhpSpreadsheet/Calculation/Information/Value.php index cdb160d7..e29144b8 100644 --- a/src/PhpSpreadsheet/Calculation/Information/Value.php +++ b/src/PhpSpreadsheet/Calculation/Information/Value.php @@ -7,6 +7,8 @@ use PhpOffice\PhpSpreadsheet\Calculation\Calculation; use PhpOffice\PhpSpreadsheet\Calculation\Functions; use PhpOffice\PhpSpreadsheet\Cell\Cell; use PhpOffice\PhpSpreadsheet\Cell\Coordinate; +use PhpOffice\PhpSpreadsheet\NamedRange; +use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet; class Value { @@ -28,11 +30,39 @@ class Value return self::evaluateSingleArgumentArray([self::class, __FUNCTION__], $value); } - if ($value !== null) { - $value = Functions::flattenSingleValue($value); + return $value === null; + } + + /** + * IS_REF. + * + * @param mixed $value Value to check + * + * @return bool + */ + public static function isRef($value, ?Cell $cell = null) + { + if ($cell === null || $value === $cell->getCoordinate()) { + return false; } - return $value === null; + $cellValue = Functions::trimTrailingRange($value); + if (preg_match('/^' . Calculation::CALCULATION_REGEXP_CELLREF . '$/ui', $cellValue) === 1) { + [$worksheet, $cellValue] = Worksheet::extractSheetTitle($cellValue, true); + if (!empty($worksheet) && $cell->getWorksheet()->getParent()->getSheetByName($worksheet) === null) { + return false; + } + [$column, $row] = Coordinate::indexesFromString($cellValue); + if ($column > 16384 || $row > 1048576) { + return false; + } + + return true; + } + + $namedRange = $cell->getWorksheet()->getParent()->getNamedRange($value); + + return $namedRange instanceof NamedRange; } /** diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/Information/IsRefTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/Information/IsRefTest.php new file mode 100644 index 00000000..04d71959 --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/Information/IsRefTest.php @@ -0,0 +1,42 @@ +getSheet(); + + $sheet->getParent()->addDefinedName(new NamedRange('NAMED_RANGE', $sheet, 'C1')); + + $sheet->getCell('A1')->setValue('=ISREF(B1)'); + $sheet->getCell('A2')->setValue('=ISREF(B1:B2)'); + $sheet->getCell('A3')->setValue('=ISREF(B1:D4 C1:C5)'); + $sheet->getCell('A4')->setValue('=ISREF("PHP")'); + $sheet->getCell('A5')->setValue('=ISREF(B1*B2)'); + $sheet->getCell('A6')->setValue('=ISREF(Worksheet2!B1)'); + $sheet->getCell('A7')->setValue('=ISREF(NAMED_RANGE)'); + $sheet->getCell('A8')->setValue('=ISREF(INDIRECT("' . $sheet->getTitle() . '" & "!" & "A1"))'); + $sheet->getCell('A9')->setValue('=ISREF(INDIRECT("A1"))'); + $sheet->getCell('A10')->setValue('=ISREF(INDIRECT("Invalid Worksheet" & "!" & "A1"))'); + $sheet->getCell('A11')->setValue('=ISREF(ZZZ1)'); + $sheet->getCell('A12')->setValue('=ISREF(CHOOSE(2, A1, B1, C1))'); + + self::assertTrue($sheet->getCell('A1')->getCalculatedValue()); // Cell Reference + self::assertTrue($sheet->getCell('A2')->getCalculatedValue()); // Cell Range + self::assertTrue($sheet->getCell('A3')->getCalculatedValue()); // Complex Cell Range + self::assertFalse($sheet->getCell('A4')->getCalculatedValue()); // Text String + self::assertFalse($sheet->getCell('A5')->getCalculatedValue()); // Result of a math expression + self::assertTrue($sheet->getCell('A6')->getCalculatedValue()); // Cell Reference with worksheet + self::assertTrue($sheet->getCell('A7')->getCalculatedValue()); // Named Range + self::assertTrue($sheet->getCell('A8')->getCalculatedValue()); // Indirect to a Cell Reference + self::assertTrue($sheet->getCell('A9')->getCalculatedValue()); // Indirect to a Worksheet/Cell Reference + self::assertFalse($sheet->getCell('A10')->getCalculatedValue()); // Indirect to an Invalid Worksheet/Cell Reference + self::assertFalse($sheet->getCell('A11')->getCalculatedValue()); // Invalid Cell Reference + self::assertTrue($sheet->getCell('A12')->getCalculatedValue()); // returned Cell Reference + } +}