Skip to content

Commit

Permalink
Add Ability to Ignore Cell Errors in Excel
Browse files Browse the repository at this point in the history
Fix PHPOffice#1141, which had been closed as stale, but which I have reopened. Excel will show cells with certain "errors" with a green triangle in the upper left. The suggestion in the issue to use quotePrefix to suppress the numberStoredAsText error is ineffective. In Excel, the user can turn this indicator off for individual cells. Cells where this is turned off can be detected at read time, and PhpSpreadsheet will now process those. In addition, the user can explicitly set the ignored error as in Excel.
```php
$cell->setIgnoredErrorNumberStoredAsText(true);
```

There are a number of different errors that can be ignored in this fashion. This PR implements `numberStoredAsText` (which is likely to be by far the most useful one), `formula`, `twoDigitTextYear`, and `evalError`, all of which are demonstrated in the new test spreadsheet. There are several others for which I am not able to create good examples; I have not implemented those, but they can be easily added if needed (`calculatedColumn`, `emptyCellReference`, `formulaRange`, `listDataValidation`, and `unlockedFormula`).
  • Loading branch information
oleibman committed Apr 3, 2023
1 parent 0e6866d commit ff61a85
Show file tree
Hide file tree
Showing 5 changed files with 222 additions and 1 deletion.
60 changes: 60 additions & 0 deletions src/PhpSpreadsheet/Cell/Cell.php
Original file line number Diff line number Diff line change
Expand Up @@ -71,6 +71,18 @@ class Cell
*/
private $formulaAttributes;

/** @var bool */
private $ignoredErrorNumberStoredAsText = false;

/** @var bool */
private $ignoredErrorFormula = false;

/** @var bool */
private $ignoredErrorTwoDigitTextYear = false;

/** @var bool */
private $ignoredErrorEvalError = false;

/**
* Update the cell into the cell collection.
*
Expand Down Expand Up @@ -796,4 +808,52 @@ public function __toString()
{
return (string) $this->getValue();
}

public function setIgnoredErrorNumberStoredAsText(bool $value): self
{
$this->ignoredErrorNumberStoredAsText = $value;

return $this;
}

public function getIgnoredErrorNumberStoredAsText(): bool
{
return $this->ignoredErrorNumberStoredAsText;
}

public function setIgnoredErrorFormula(bool $value): self
{
$this->ignoredErrorFormula = $value;

return $this;
}

public function getIgnoredErrorFormula(): bool
{
return $this->ignoredErrorFormula;
}

public function setIgnoredErrorTwoDigitTextYear(bool $value): self
{
$this->ignoredErrorTwoDigitTextYear = $value;

return $this;
}

public function getIgnoredErrorTwoDigitTextYear(): bool
{
return $this->ignoredErrorTwoDigitTextYear;
}

public function setIgnoredErrorEvalError(bool $value): self
{
$this->ignoredErrorEvalError = $value;

return $this;
}

public function getIgnoredErrorEvalError(): bool
{
return $this->ignoredErrorEvalError;
}
}
49 changes: 49 additions & 0 deletions src/PhpSpreadsheet/Reader/Xlsx.php
Original file line number Diff line number Diff line change
Expand Up @@ -915,6 +915,11 @@ protected function loadSpreadsheetFromFile(string $filename): Spreadsheet
++$cIndex;
}
}
if ($xmlSheetNS && $xmlSheetNS->ignoredErrors) {
foreach ($xmlSheetNS->ignoredErrors->ignoredError as $ignoredError) {
$this->processIgnoredErrors($ignoredError, $docSheet);
}
}

if (!$this->readDataOnly && $xmlSheetNS && $xmlSheetNS->sheetProtection) {
$protAttr = $xmlSheetNS->sheetProtection->attributes() ?? [];
Expand Down Expand Up @@ -2222,4 +2227,48 @@ private static function extractPalette(?SimpleXMLElement $sxml): array

return $array;
}

private function processIgnoredErrors(SimpleXMLElement $xml, Worksheet $sheet): void
{
$attributes = self::getAttributes($xml);
$sqref = (string) ($attributes['sqref'] ?? '');
$numberStoredAsText = (string) ($attributes['numberStoredAsText'] ?? '');
$formula = (string) ($attributes['formula'] ?? '');
$twoDigitTextYear = (string) ($attributes['twoDigitTextYear'] ?? '');
$evalError = (string) ($attributes['evalError'] ?? '');
if (!empty($sqref)) {
$explodedSqref = explode(' ', $sqref);
$pattern1 = '/^([A-Z]{1,3})([0-9]{1,7})(:([A-Z]{1,3})([0-9]{1,7}))?$/';
foreach ($explodedSqref as $sqref1) {
if (preg_match($pattern1, $sqref1, $matches) === 1) {
$firstRow = $matches[2];
$firstCol = $matches[1];
if (array_key_exists(3, $matches)) {
$lastCol = $matches[4];
$lastRow = $matches[5];
} else {
$lastCol = $firstCol;
$lastRow = $firstRow;
}
++$lastCol;
for ($row = $firstRow; $row <= $lastRow; ++$row) {
for ($col = $firstCol; $col !== $lastCol; ++$col) {
if ($numberStoredAsText === '1') {
$sheet->getCell("$col$row")->setIgnoredErrorNumberStoredAsText(true);
}
if ($formula === '1') {
$sheet->getCell("$col$row")->setIgnoredErrorFormula(true);
}
if ($twoDigitTextYear === '1') {
$sheet->getCell("$col$row")->setIgnoredErrorTwoDigitTextYear(true);
}
if ($evalError === '1') {
$sheet->getCell("$col$row")->setIgnoredErrorEvalError(true);
}
}
}
}
}
}
}
}
56 changes: 55 additions & 1 deletion src/PhpSpreadsheet/Writer/Xlsx/Worksheet.php
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,18 @@

class Worksheet extends WriterPart
{
/** @var string */
private $numberStoredAsText = '';

/** @var string */
private $formula = '';

/** @var string */
private $twoDigitTextYear = '';

/** @var string */
private $evalError = '';

/**
* Write worksheet to XML format.
*
Expand Down Expand Up @@ -118,6 +130,9 @@ public function writeWorksheet(PhpspreadsheetWorksheet $worksheet, $stringTable
// AlternateContent
$this->writeAlternateContent($objWriter, $worksheet);

// IgnoredErrors
$this->writeIgnoredErrors($objWriter);

// Table
$this->writeTable($objWriter, $worksheet);

Expand All @@ -131,6 +146,32 @@ public function writeWorksheet(PhpspreadsheetWorksheet $worksheet, $stringTable
return $objWriter->getData();
}

private function writeIgnoredError(XMLWriter $objWriter, bool &$started, string $attr, string $cells): void
{
if ($cells !== '') {
if (!$started) {
$objWriter->startElement('ignoredErrors');
$started = true;
}
$objWriter->startElement('ignoredError');
$objWriter->writeAttribute('sqref', substr($cells, 1));
$objWriter->writeAttribute($attr, '1');
$objWriter->endElement();
}
}

private function writeIgnoredErrors(XMLWriter $objWriter): void
{
$started = false;
$this->writeIgnoredError($objWriter, $started, 'numberStoredAsText', $this->numberStoredAsText);
$this->writeIgnoredError($objWriter, $started, 'formula', $this->formula);
$this->writeIgnoredError($objWriter, $started, 'twoDigitTextYear', $this->twoDigitTextYear);
$this->writeIgnoredError($objWriter, $started, 'evalError', $this->evalError);
if ($started) {
$objWriter->endElement();
}
}

/**
* Write SheetPr.
*/
Expand Down Expand Up @@ -1134,7 +1175,20 @@ private function writeSheetData(XMLWriter $objWriter, PhpspreadsheetWorksheet $w
array_pop($columnsInRow);
foreach ($columnsInRow as $column) {
// Write cell
$this->writeCell($objWriter, $worksheet, "{$column}{$currentRow}", $aFlippedStringTable);
$coord = "$column$currentRow";
if ($worksheet->getCell($coord)->getIgnoredErrorNumberStoredAsText()) {
$this->numberStoredAsText .= " $coord";
}
if ($worksheet->getCell($coord)->getIgnoredErrorFormula()) {
$this->formula .= " $coord";
}
if ($worksheet->getCell($coord)->getIgnoredErrorTwoDigitTextYear()) {
$this->twoDigitTextYear .= " $coord";
}
if ($worksheet->getCell($coord)->getIgnoredErrorEvalError()) {
$this->evalError .= " $coord";
}
$this->writeCell($objWriter, $worksheet, $coord, $aFlippedStringTable);
}
}

Expand Down
58 changes: 58 additions & 0 deletions tests/PhpSpreadsheetTests/Reader/Xlsx/IgnoredErrorTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
<?php

namespace PhpOffice\PhpSpreadsheetTests\Reader\Xlsx;

use PhpOffice\PhpSpreadsheet\Cell\DataType;
use PhpOffice\PhpSpreadsheet\Reader\Xlsx;
use PhpOffice\PhpSpreadsheet\Spreadsheet;
use PhpOffice\PhpSpreadsheetTests\Functional\AbstractFunctional;

class IgnoredErrorTest extends AbstractFunctional
{
private const FILENAME = 'tests/data/Reader/XLSX/ignoreerror.xlsx';

public function testIgnoredError(): void
{
$reader = new Xlsx();
$originalSpreadsheet = $reader->load(self::FILENAME);
$spreadsheet = $this->writeAndReload($originalSpreadsheet, 'Xlsx');
$originalSpreadsheet->disconnectWorksheets();
$sheet = $spreadsheet->getActiveSheet();
self::assertFalse($sheet->getCell('A1')->getIgnoredErrorNumberStoredAsText());
self::assertTrue($sheet->getCell('A2')->getIgnoredErrorNumberStoredAsText());
self::assertFalse($sheet->getCell('H2')->getIgnoredErrorNumberStoredAsText());
self::assertTrue($sheet->getCell('H3')->getIgnoredErrorNumberStoredAsText());
self::assertFalse($sheet->getCell('I2')->getIgnoredErrorNumberStoredAsText());
self::assertTrue($sheet->getCell('I3')->getIgnoredErrorNumberStoredAsText());

self::assertFalse($sheet->getCell('H3')->getIgnoredErrorFormula());
self::assertFalse($sheet->getCell('D2')->getIgnoredErrorFormula());
self::assertTrue($sheet->getCell('D3')->getIgnoredErrorFormula());

self::assertFalse($sheet->getCell('A11')->getIgnoredErrorTwoDigitTextYear());
self::assertTrue($sheet->getCell('A12')->getIgnoredErrorTwoDigitTextYear());

self::assertFalse($sheet->getCell('C12')->getIgnoredErrorEvalError());
self::assertTrue($sheet->getCell('C11')->getIgnoredErrorEvalError());

$spreadsheet->disconnectWorksheets();
}

public function testSetIgnoredError(): void
{
$originalSpreadsheet = new Spreadsheet();
$originalSheet = $originalSpreadsheet->getActiveSheet();
$originalSheet->getCell('A1')->setValueExplicit('0', DataType::TYPE_STRING);
$originalSheet->getCell('A2')->setValueExplicit('1', DataType::TYPE_STRING);
$originalSheet->getStyle('A1:A2')->setQuotePrefix(true);
$originalSheet->getCell('A2')->setIgnoredErrorNumberStoredAsText(true);
$spreadsheet = $this->writeAndReload($originalSpreadsheet, 'Xlsx');
$originalSpreadsheet->disconnectWorksheets();
$sheet = $spreadsheet->getActiveSheet();
self::assertSame('0', $sheet->getCell('A1')->getValue());
self::assertSame('1', $sheet->getCell('A2')->getValue());
self::assertFalse($sheet->getCell('A1')->getIgnoredErrorNumberStoredAsText());
self::assertTrue($sheet->getCell('A2')->getIgnoredErrorNumberStoredAsText());
$spreadsheet->disconnectWorksheets();
}
}
Binary file added tests/data/Reader/XLSX/ignoreerror.xlsx
Binary file not shown.

0 comments on commit ff61a85

Please sign in to comment.