Handle Explicit "Date" Type for Cell (#2485)

Fix #2373. Excel can handle DateTime/Date/Time as a string if the datatype of the cell is set to "d". The string is, apparently, supposed to follow the ISO8601 spec. Openpyxl can be configured to generate a file with such values, so I've added support and set up unit tests. Excel, naturally, converts such a string input into its numeric representation of the date/time stamp. So will PhpSpreadsheet, so a call to setValueExplicit specifying Date format will actually see the cell wind up with Numeric format - there is no way (and no reason) for the Date type to 'stick'.
This commit is contained in:
oleibman 2022-01-13 18:40:18 -08:00 committed by GitHub
parent 1a359d2ccb
commit 8ab834520d
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
5 changed files with 72 additions and 1 deletions

View File

@ -2,10 +2,12 @@
namespace PhpOffice\PhpSpreadsheet\Cell; namespace PhpOffice\PhpSpreadsheet\Cell;
use DateTime;
use PhpOffice\PhpSpreadsheet\Calculation\Calculation; use PhpOffice\PhpSpreadsheet\Calculation\Calculation;
use PhpOffice\PhpSpreadsheet\Collection\Cells; use PhpOffice\PhpSpreadsheet\Collection\Cells;
use PhpOffice\PhpSpreadsheet\Exception; use PhpOffice\PhpSpreadsheet\Exception;
use PhpOffice\PhpSpreadsheet\RichText\RichText; use PhpOffice\PhpSpreadsheet\RichText\RichText;
use PhpOffice\PhpSpreadsheet\Shared\Date as SharedDate;
use PhpOffice\PhpSpreadsheet\Style\NumberFormat; use PhpOffice\PhpSpreadsheet\Style\NumberFormat;
use PhpOffice\PhpSpreadsheet\Style\Style; use PhpOffice\PhpSpreadsheet\Style\Style;
use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet; use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet;
@ -234,6 +236,22 @@ class Cell
case DataType::TYPE_BOOL: case DataType::TYPE_BOOL:
$this->value = (bool) $value; $this->value = (bool) $value;
break;
case DataType::TYPE_ISO_DATE:
if (!is_string($value)) {
throw new Exception('Non-string supplied for datatype Date');
}
$date = new DateTime($value);
$newValue = SharedDate::PHPToExcel($date);
if ($newValue === false) {
throw new Exception("Invalid string $value supplied for datatype Date");
}
if (preg_match('/^\\d\\d:\\d\\d:\\d\\d/', $value) == 1) {
$newValue = fmod($newValue, 1.0);
}
$this->value = $newValue;
$dataType = DataType::TYPE_NUMERIC;
break; break;
case DataType::TYPE_ERROR: case DataType::TYPE_ERROR:
$this->value = DataType::checkErrorCode($value); $this->value = DataType::checkErrorCode($value);

View File

@ -16,6 +16,7 @@ class DataType
const TYPE_NULL = 'null'; const TYPE_NULL = 'null';
const TYPE_INLINE = 'inlineStr'; const TYPE_INLINE = 'inlineStr';
const TYPE_ERROR = 'e'; const TYPE_ERROR = 'e';
const TYPE_ISO_DATE = 'd';
/** /**
* List of error codes. * List of error codes.

View File

@ -228,7 +228,7 @@ class Date
* @param mixed $dateValue PHP DateTime object or a string - Unix timestamp is also permitted, but discouraged; * @param mixed $dateValue PHP DateTime object or a string - Unix timestamp is also permitted, but discouraged;
* not Y2038-safe on a 32-bit system, and no timezone info * not Y2038-safe on a 32-bit system, and no timezone info
* *
* @return bool|float Excel date/time value * @return false|float Excel date/time value
* or boolean FALSE on failure * or boolean FALSE on failure
*/ */
public static function PHPToExcel($dateValue) public static function PHPToExcel($dateValue)

View File

@ -0,0 +1,52 @@
<?php
namespace PhpOffice\PhpSpreadsheetTests\Reader\Xlsx;
use PhpOffice\PhpSpreadsheet\IOFactory;
class ExplicitDateTest extends \PHPUnit\Framework\TestCase
{
/**
* @var string
*/
private static $testbook = 'tests/data/Reader/XLSX/explicitdate.xlsx';
public function testPreliminaries(): void
{
$file = 'zip://';
$file .= self::$testbook;
$file .= '#xl/worksheets/sheet1.xml';
$data = file_get_contents($file);
if ($data === false) {
self::fail('Unable to read file');
} else {
// confirm that file contains type "d" cells
self::assertStringContainsString('<c r="A3" s="1" t="d"><v>2021-12-31T23:44:51.894</v></c>', $data);
self::assertStringContainsString('<c r="B3" s="2" t="d"><v>2021-12-31</v></c>', $data);
self::assertStringContainsString('<c r="C3" s="3" t="d"><v>23:44:51.894</v></c>', $data);
}
}
public static function testExplicitDate(): void
{
$spreadsheet = IOFactory::load(self::$testbook);
$sheet = $spreadsheet->getActiveSheet();
// DateTime
$value = $sheet->getCell('A3')->getValue();
$formatted = $sheet->getCell('A3')->getFormattedValue();
self::assertEqualsWithDelta(44561.98948, $value, 0.00001);
self::assertSame('2021-12-31 23:44:51', $formatted);
// Date only
$value = $sheet->getCell('B3')->getValue();
$formatted = $sheet->getCell('B3')->getFormattedValue();
self::assertEquals(44561, $value);
self::assertSame('2021-12-31', $formatted);
// Time only
$value = $sheet->getCell('C3')->getValue();
$formatted = $sheet->getCell('C3')->getFormattedValue();
self::assertEqualsWithDelta(0.98948, $value, 0.00001);
self::assertSame('23:44:51', $formatted);
$spreadsheet->disconnectWorksheets();
}
}

Binary file not shown.