From 3884aa74773d4b9b3275176c633cf9f8f3610245 Mon Sep 17 00:00:00 2001 From: MarkBaker Date: Sat, 3 Sep 2022 22:03:16 +0200 Subject: [PATCH] Update Excel function samples for Date/Time functions --- samples/Calculations/DateTime/DATE.php | 16 ++++-- samples/Calculations/DateTime/DATEDIF.php | 60 ++++++++++++++++++++ samples/Calculations/DateTime/DATEVALUE.php | 18 +++--- samples/Calculations/DateTime/DAY.php | 50 ++++++++++++++++ samples/Calculations/DateTime/DAYS.php | 52 +++++++++++++++++ samples/Calculations/DateTime/DAYS360.php | 57 +++++++++++++++++++ samples/Calculations/DateTime/EDATE.php | 43 ++++++++++++++ samples/Calculations/DateTime/EOMONTH.php | 43 ++++++++++++++ samples/Calculations/DateTime/HOUR.php | 48 ++++++++++++++++ samples/Calculations/DateTime/ISOWEEKNUM.php | 50 ++++++++++++++++ samples/Calculations/DateTime/MINUTE.php | 48 ++++++++++++++++ samples/Calculations/DateTime/MONTH.php | 50 ++++++++++++++++ samples/Calculations/DateTime/NOW.php | 27 +++++++++ samples/Calculations/DateTime/SECOND.php | 48 ++++++++++++++++ samples/Calculations/DateTime/TIME.php | 14 +++-- samples/Calculations/DateTime/TIMEVALUE.php | 8 ++- samples/Calculations/DateTime/TODAY.php | 27 +++++++++ samples/Calculations/DateTime/WEEKDAY.php | 58 +++++++++++++++++++ samples/Calculations/DateTime/WEEKNUM.php | 52 +++++++++++++++++ samples/Calculations/DateTime/YEAR.php | 50 ++++++++++++++++ src/PhpSpreadsheet/Helper/Sample.php | 4 +- 21 files changed, 801 insertions(+), 22 deletions(-) create mode 100644 samples/Calculations/DateTime/DATEDIF.php create mode 100644 samples/Calculations/DateTime/DAY.php create mode 100644 samples/Calculations/DateTime/DAYS.php create mode 100644 samples/Calculations/DateTime/DAYS360.php create mode 100644 samples/Calculations/DateTime/EDATE.php create mode 100644 samples/Calculations/DateTime/EOMONTH.php create mode 100644 samples/Calculations/DateTime/HOUR.php create mode 100644 samples/Calculations/DateTime/ISOWEEKNUM.php create mode 100644 samples/Calculations/DateTime/MINUTE.php create mode 100644 samples/Calculations/DateTime/MONTH.php create mode 100644 samples/Calculations/DateTime/NOW.php create mode 100644 samples/Calculations/DateTime/SECOND.php create mode 100644 samples/Calculations/DateTime/TODAY.php create mode 100644 samples/Calculations/DateTime/WEEKDAY.php create mode 100644 samples/Calculations/DateTime/WEEKNUM.php create mode 100644 samples/Calculations/DateTime/YEAR.php diff --git a/samples/Calculations/DateTime/DATE.php b/samples/Calculations/DateTime/DATE.php index 5d758f76..d526cbdb 100644 --- a/samples/Calculations/DateTime/DATE.php +++ b/samples/Calculations/DateTime/DATE.php @@ -4,7 +4,11 @@ use PhpOffice\PhpSpreadsheet\Spreadsheet; require __DIR__ . '/../../Header.php'; -$helper->log('Returns the serial number of a particular date.'); +$category = 'Date/Time'; +$functionName = 'DATE'; +$description = 'Returns the Excel serial number of a particular date'; + +$helper->titles($category, $functionName, $description); // Create new PhpSpreadsheet object $spreadsheet = new Spreadsheet(); @@ -27,15 +31,15 @@ for ($row = 1; $row <= $testDateCount; ++$row) { } $worksheet->getStyle('E1:E' . $testDateCount) ->getNumberFormat() - ->setFormatCode('yyyy-mmm-dd'); + ->setFormatCode('yyyy-mm-dd'); // Test the formulae for ($row = 1; $row <= $testDateCount; ++$row) { - $helper->log('Year: ' . $worksheet->getCell('A' . $row)->getFormattedValue()); - $helper->log('Month: ' . $worksheet->getCell('B' . $row)->getFormattedValue()); - $helper->log('Day: ' . $worksheet->getCell('C' . $row)->getFormattedValue()); + $helper->log("(A{$row}) Year: " . $worksheet->getCell('A' . $row)->getFormattedValue()); + $helper->log("(B{$row}) Month: " . $worksheet->getCell('B' . $row)->getFormattedValue()); + $helper->log("(C{$row}) Day: " . $worksheet->getCell('C' . $row)->getFormattedValue()); $helper->log('Formula: ' . $worksheet->getCell('D' . $row)->getValue()); - $helper->log('Excel DateStamp: ' . $worksheet->getCell('D' . $row)->getFormattedValue()); + $helper->log('Excel DateStamp: ' . $worksheet->getCell('D' . $row)->getCalculatedValue()); $helper->log('Formatted DateStamp: ' . $worksheet->getCell('E' . $row)->getFormattedValue()); $helper->log(''); } diff --git a/samples/Calculations/DateTime/DATEDIF.php b/samples/Calculations/DateTime/DATEDIF.php new file mode 100644 index 00000000..7bc077c9 --- /dev/null +++ b/samples/Calculations/DateTime/DATEDIF.php @@ -0,0 +1,60 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 1, 1], + [1936, 3, 17], + [1960, 12, 19], + [1999, 12, 31], + [2000, 1, 1], + [2019, 2, 14], + [2020, 7, 4], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=TODAY()'); + $worksheet->setCellValue('G' . $row, '=DATEDIF(D' . $row . ', F' . $row . ', "Y")'); + $worksheet->setCellValue('H' . $row, '=DATEDIF(D' . $row . ', F' . $row . ', "M")'); + $worksheet->setCellValue('I' . $row, '=DATEDIF(D' . $row . ', F' . $row . ', "D")'); + $worksheet->setCellValue('J' . $row, '=DATEDIF(D' . $row . ', F' . $row . ', "MD")'); + $worksheet->setCellValue('K' . $row, '=DATEDIF(D' . $row . ', F' . $row . ', "YM")'); + $worksheet->setCellValue('L' . $row, '=DATEDIF(D' . $row . ', F' . $row . ', "YD")'); +} +$worksheet->getStyle('E1:F' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf( + 'Between: %s and %s', + $worksheet->getCell('E' . $row)->getFormattedValue(), + $worksheet->getCell('F' . $row)->getFormattedValue() + )); + $helper->log('In years ("Y"): ' . $worksheet->getCell('G' . $row)->getCalculatedValue()); + $helper->log('In months ("M"): ' . $worksheet->getCell('H' . $row)->getCalculatedValue()); + $helper->log('In days ("D"): ' . $worksheet->getCell('I' . $row)->getCalculatedValue()); + $helper->log('In days ignoring months and years ("MD"): ' . $worksheet->getCell('J' . $row)->getCalculatedValue()); + $helper->log('In months ignoring days and years ("YM"): ' . $worksheet->getCell('K' . $row)->getCalculatedValue()); + $helper->log('In days ignoring years ("YD"): ' . $worksheet->getCell('L' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/DATEVALUE.php b/samples/Calculations/DateTime/DATEVALUE.php index 5cdb936d..c506c6f2 100644 --- a/samples/Calculations/DateTime/DATEVALUE.php +++ b/samples/Calculations/DateTime/DATEVALUE.php @@ -4,7 +4,11 @@ use PhpOffice\PhpSpreadsheet\Spreadsheet; require __DIR__ . '/../../Header.php'; -$helper->log('Converts a date in the form of text to a serial number.'); +$category = 'Date/Time'; +$functionName = 'DATEVALUE'; +$description = 'Converts a date in the form of text to an Excel serial number'; + +$helper->titles($category, $functionName, $description); // Create new PhpSpreadsheet object $spreadsheet = new Spreadsheet(); @@ -13,8 +17,8 @@ $worksheet = $spreadsheet->getActiveSheet(); // Add some data $testDates = ['26 March 2012', '29 Feb 2012', 'April 1, 2012', '25/12/2012', '2012-Oct-31', '5th November', 'January 1st', 'April 2012', - '17-03', '03-2012', '29 Feb 2011', '03-05-07', - '03-MAY-07', '03-13-07', + '17-03', '03-17', '03-2012', '29 Feb 2011', '03-05-07', + '03-MAY-07', '03-13-07', '13-03-07', '03/13/07', '13/03/07', ]; $testDateCount = count($testDates); @@ -26,14 +30,14 @@ for ($row = 1; $row <= $testDateCount; ++$row) { $worksheet->getStyle('C1:C' . $testDateCount) ->getNumberFormat() - ->setFormatCode('yyyy-mmm-dd'); + ->setFormatCode('yyyy-mm-dd'); // Test the formulae $helper->log('Warning: The PhpSpreadsheet DATEVALUE() function accepts a wider range of date formats than MS Excel DATEFORMAT() function.'); for ($row = 1; $row <= $testDateCount; ++$row) { - $helper->log('Date String: ' . $worksheet->getCell('A' . $row)->getFormattedValue()); + $helper->log("(A{$row}) Date String: " . $worksheet->getCell('A' . $row)->getFormattedValue()); $helper->log('Formula: ' . $worksheet->getCell('B' . $row)->getValue()); - $helper->log('Excel DateStamp: ' . $worksheet->getCell('B' . $row)->getFormattedValue()); - $helper->log('Formatted DateStamp' . $worksheet->getCell('C' . $row)->getFormattedValue()); + $helper->log('Excel DateStamp: ' . $worksheet->getCell('B' . $row)->getCalculatedValue()); + $helper->log('Formatted DateStamp: ' . $worksheet->getCell('C' . $row)->getFormattedValue()); $helper->log(''); } diff --git a/samples/Calculations/DateTime/DAY.php b/samples/Calculations/DateTime/DAY.php new file mode 100644 index 00000000..3a4da7e6 --- /dev/null +++ b/samples/Calculations/DateTime/DAY.php @@ -0,0 +1,50 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 2, 14], + [1936, 3, 17], + [1964, 4, 29], + [1999, 5, 18], + [2000, 6, 21], + [2019, 7, 4], + [2020, 8, 31], + [1956, 9, 10], + [2010, 10, 10], + [1982, 11, 30], + [1960, 12, 19], + ['=YEAR(TODAY())', '=MONTH(TODAY())', '=DAY(TODAY())'], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=DAY(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('Day is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/DAYS.php b/samples/Calculations/DateTime/DAYS.php new file mode 100644 index 00000000..ddd47f37 --- /dev/null +++ b/samples/Calculations/DateTime/DAYS.php @@ -0,0 +1,52 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 1, 1], + [1936, 3, 17], + [1960, 12, 19], + [1999, 12, 31], + [2000, 1, 1], + [2019, 2, 14], + [2020, 7, 4], + [2029, 12, 31], + [2525, 1, 1], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=TODAY()'); + $worksheet->setCellValue('G' . $row, '=DAYS(D' . $row . ', F' . $row . ')'); +} +$worksheet->getStyle('E1:F' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf( + 'Between: %s and %s', + $worksheet->getCell('E' . $row)->getFormattedValue(), + $worksheet->getCell('F' . $row)->getFormattedValue() + )); + $helper->log('Days: ' . $worksheet->getCell('G' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/DAYS360.php b/samples/Calculations/DateTime/DAYS360.php new file mode 100644 index 00000000..b0e2fdbb --- /dev/null +++ b/samples/Calculations/DateTime/DAYS360.php @@ -0,0 +1,57 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 1, 1], + [1936, 3, 17], + [1960, 12, 19], + [1999, 12, 31], + [2000, 1, 1], + [2019, 2, 14], + [2020, 7, 4], + [2029, 12, 31], + [2525, 1, 1], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=DATE(2022,12,31)'); + $worksheet->setCellValue('G' . $row, '=DAYS360(D' . $row . ', F' . $row . ', FALSE)'); + $worksheet->setCellValue('H' . $row, '=DAYS360(D' . $row . ', F' . $row . ', TRUE)'); +} +$worksheet->getStyle('E1:F' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf( + 'Between: %s and %s', + $worksheet->getCell('E' . $row)->getFormattedValue(), + $worksheet->getCell('F' . $row)->getFormattedValue() + )); + $helper->log(sprintf( + 'Days: %d (US) %d (European)', + $worksheet->getCell('G' . $row)->getCalculatedValue(), + $worksheet->getCell('H' . $row)->getCalculatedValue() + )); +} diff --git a/samples/Calculations/DateTime/EDATE.php b/samples/Calculations/DateTime/EDATE.php new file mode 100644 index 00000000..be6e4d19 --- /dev/null +++ b/samples/Calculations/DateTime/EDATE.php @@ -0,0 +1,43 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +$months = range(-12, 12); +$testDateCount = count($months); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('A' . $row, '=DATE(2020,12,31)'); + $worksheet->setCellValue('B' . $row, '=A' . $row); + $worksheet->setCellValue('C' . $row, $months[$row - 1]); + $worksheet->setCellValue('D' . $row, '=EDATE(B' . $row . ', C' . $row . ')'); +} +$worksheet->getStyle('B1:B' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +$worksheet->getStyle('D1:D' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf( + '%s and %d months is %d (%s)', + $worksheet->getCell('B' . $row)->getFormattedValue(), + $worksheet->getCell('C' . $row)->getFormattedValue(), + $worksheet->getCell('D' . $row)->getCalculatedValue(), + $worksheet->getCell('D' . $row)->getFormattedValue() + )); +} diff --git a/samples/Calculations/DateTime/EOMONTH.php b/samples/Calculations/DateTime/EOMONTH.php new file mode 100644 index 00000000..e0b7568a --- /dev/null +++ b/samples/Calculations/DateTime/EOMONTH.php @@ -0,0 +1,43 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +$months = range(-12, 12); +$testDateCount = count($months); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('A' . $row, '=DATE(2020,1,1)'); + $worksheet->setCellValue('B' . $row, '=A' . $row); + $worksheet->setCellValue('C' . $row, $months[$row - 1]); + $worksheet->setCellValue('D' . $row, '=EOMONTH(B' . $row . ', C' . $row . ')'); +} +$worksheet->getStyle('B1:B' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +$worksheet->getStyle('D1:D' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf( + '%s and %d months is %d (%s)', + $worksheet->getCell('B' . $row)->getFormattedValue(), + $worksheet->getCell('C' . $row)->getFormattedValue(), + $worksheet->getCell('D' . $row)->getCalculatedValue(), + $worksheet->getCell('D' . $row)->getFormattedValue() + )); +} diff --git a/samples/Calculations/DateTime/HOUR.php b/samples/Calculations/DateTime/HOUR.php new file mode 100644 index 00000000..53c21644 --- /dev/null +++ b/samples/Calculations/DateTime/HOUR.php @@ -0,0 +1,48 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testTimes = [ + [0, 6, 0], + [1, 12, 15], + [3, 30, 12], + [5, 17, 31], + [8, 15, 45], + [12, 45, 11], + [14, 0, 30], + [17, 55, 50], + [19, 21, 8], + [21, 10, 10], + [23, 59, 59], +]; +$testTimeCount = count($testTimes); + +$worksheet->fromArray($testTimes, null, 'A1', true); + +for ($row = 1; $row <= $testTimeCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=TIME(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=HOUR(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testTimeCount) + ->getNumberFormat() + ->setFormatCode('hh:mm:ss'); + +// Test the formulae +for ($row = 1; $row <= $testTimeCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('Hour is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/ISOWEEKNUM.php b/samples/Calculations/DateTime/ISOWEEKNUM.php new file mode 100644 index 00000000..4a989fbd --- /dev/null +++ b/samples/Calculations/DateTime/ISOWEEKNUM.php @@ -0,0 +1,50 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 2, 14], + [1936, 3, 17], + [1964, 4, 29], + [1999, 5, 18], + [2000, 6, 21], + [2019, 7, 4], + [2020, 8, 31], + [1956, 9, 10], + [2010, 10, 10], + [1982, 11, 30], + [1960, 12, 19], + ['=YEAR(TODAY())', '=MONTH(TODAY())', '=DAY(TODAY())'], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=ISOWEEKNUM(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('ISO Week number is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/MINUTE.php b/samples/Calculations/DateTime/MINUTE.php new file mode 100644 index 00000000..11e90e13 --- /dev/null +++ b/samples/Calculations/DateTime/MINUTE.php @@ -0,0 +1,48 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testTimes = [ + [0, 6, 0], + [1, 12, 15], + [3, 30, 12], + [5, 17, 31], + [8, 15, 45], + [12, 45, 11], + [14, 0, 30], + [17, 55, 50], + [19, 21, 8], + [21, 10, 10], + [23, 59, 59], +]; +$testTimeCount = count($testTimes); + +$worksheet->fromArray($testTimes, null, 'A1', true); + +for ($row = 1; $row <= $testTimeCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=TIME(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=MINUTE(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testTimeCount) + ->getNumberFormat() + ->setFormatCode('hh:mm:ss'); + +// Test the formulae +for ($row = 1; $row <= $testTimeCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('Minute is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/MONTH.php b/samples/Calculations/DateTime/MONTH.php new file mode 100644 index 00000000..8cceaf4c --- /dev/null +++ b/samples/Calculations/DateTime/MONTH.php @@ -0,0 +1,50 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 2, 14], + [1936, 3, 17], + [1964, 4, 29], + [1999, 5, 18], + [2000, 6, 21], + [2019, 7, 4], + [2020, 8, 31], + [1956, 9, 10], + [2010, 10, 10], + [1982, 11, 30], + [1960, 12, 19], + ['=YEAR(TODAY())', '=MONTH(TODAY())', '=DAY(TODAY())'], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=MONTH(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('Month is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/NOW.php b/samples/Calculations/DateTime/NOW.php new file mode 100644 index 00000000..858a3162 --- /dev/null +++ b/samples/Calculations/DateTime/NOW.php @@ -0,0 +1,27 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +$worksheet->setCellValue('A1', '=NOW()'); +$worksheet->getStyle('A1') + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd hh:mm:ss'); + +// Test the formulae +$helper->log(sprintf( + 'Today is %f (%s)', + $worksheet->getCell('A1')->getCalculatedValue(), + $worksheet->getCell('A1')->getFormattedValue() +)); diff --git a/samples/Calculations/DateTime/SECOND.php b/samples/Calculations/DateTime/SECOND.php new file mode 100644 index 00000000..33806fd5 --- /dev/null +++ b/samples/Calculations/DateTime/SECOND.php @@ -0,0 +1,48 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testTimes = [ + [0, 6, 0], + [1, 12, 15], + [3, 30, 12], + [5, 17, 31], + [8, 15, 45], + [12, 45, 11], + [14, 0, 30], + [17, 55, 50], + [19, 21, 8], + [21, 10, 10], + [23, 59, 59], +]; +$testTimeCount = count($testTimes); + +$worksheet->fromArray($testTimes, null, 'A1', true); + +for ($row = 1; $row <= $testTimeCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=TIME(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=SECOND(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testTimeCount) + ->getNumberFormat() + ->setFormatCode('hh:mm:ss'); + +// Test the formulae +for ($row = 1; $row <= $testTimeCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('Second is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/TIME.php b/samples/Calculations/DateTime/TIME.php index 3d4208ad..42c45488 100644 --- a/samples/Calculations/DateTime/TIME.php +++ b/samples/Calculations/DateTime/TIME.php @@ -4,7 +4,11 @@ use PhpOffice\PhpSpreadsheet\Spreadsheet; require __DIR__ . '/../../Header.php'; -$helper->log('Returns the serial number of a particular time.'); +$category = 'Date/Time'; +$functionName = 'TIME'; +$description = 'Returns the Excel serial number of a particular time'; + +$helper->titles($category, $functionName, $description); // Create new PhpSpreadsheet object $spreadsheet = new Spreadsheet(); @@ -29,11 +33,11 @@ $worksheet->getStyle('E1:E' . $testDateCount) // Test the formulae for ($row = 1; $row <= $testDateCount; ++$row) { - $helper->log('Hour: ' . $worksheet->getCell('A' . $row)->getFormattedValue()); - $helper->log('Minute: ' . $worksheet->getCell('B' . $row)->getFormattedValue()); - $helper->log('Second: ' . $worksheet->getCell('C' . $row)->getFormattedValue()); + $helper->log("(A{$row}) Hour: " . $worksheet->getCell('A' . $row)->getFormattedValue()); + $helper->log("(B{$row}) Minute: " . $worksheet->getCell('B' . $row)->getFormattedValue()); + $helper->log("(C{$row}) Second: " . $worksheet->getCell('C' . $row)->getFormattedValue()); $helper->log('Formula: ' . $worksheet->getCell('D' . $row)->getValue()); - $helper->log('Excel TimeStamp: ' . $worksheet->getCell('D' . $row)->getFormattedValue()); + $helper->log('Excel TimeStamp: ' . $worksheet->getCell('D' . $row)->getCalculatedValue()); $helper->log('Formatted TimeStamp: ' . $worksheet->getCell('E' . $row)->getFormattedValue()); $helper->log(''); } diff --git a/samples/Calculations/DateTime/TIMEVALUE.php b/samples/Calculations/DateTime/TIMEVALUE.php index f75393cd..15ea8cd9 100644 --- a/samples/Calculations/DateTime/TIMEVALUE.php +++ b/samples/Calculations/DateTime/TIMEVALUE.php @@ -4,7 +4,11 @@ use PhpOffice\PhpSpreadsheet\Spreadsheet; require __DIR__ . '/../../Header.php'; -$helper->log('Converts a time in the form of text to a serial number.'); +$category = 'Date/Time'; +$functionName = 'DATEVALUE'; +$description = 'Converts a time in the form of text to an Excel serial number'; + +$helper->titles($category, $functionName, $description); // Create new PhpSpreadsheet object $spreadsheet = new Spreadsheet(); @@ -27,7 +31,7 @@ $worksheet->getStyle('C1:C' . $testDateCount) // Test the formulae for ($row = 1; $row <= $testDateCount; ++$row) { - $helper->log('Time String: ' . $worksheet->getCell('A' . $row)->getFormattedValue()); + $helper->log("(A{$row}) Time String: " . $worksheet->getCell('A' . $row)->getFormattedValue()); $helper->log('Formula: ' . $worksheet->getCell('B' . $row)->getValue()); $helper->log('Excel TimeStamp: ' . $worksheet->getCell('B' . $row)->getFormattedValue()); $helper->log('Formatted TimeStamp: ' . $worksheet->getCell('C' . $row)->getFormattedValue()); diff --git a/samples/Calculations/DateTime/TODAY.php b/samples/Calculations/DateTime/TODAY.php new file mode 100644 index 00000000..031149d5 --- /dev/null +++ b/samples/Calculations/DateTime/TODAY.php @@ -0,0 +1,27 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +$worksheet->setCellValue('A1', '=TODAY()'); +$worksheet->getStyle('A1') + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +$helper->log(sprintf( + 'Today is %d (%s)', + $worksheet->getCell('A1')->getCalculatedValue(), + $worksheet->getCell('A1')->getFormattedValue() +)); diff --git a/samples/Calculations/DateTime/WEEKDAY.php b/samples/Calculations/DateTime/WEEKDAY.php new file mode 100644 index 00000000..7d4b4288 --- /dev/null +++ b/samples/Calculations/DateTime/WEEKDAY.php @@ -0,0 +1,58 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 2, 14], + [1936, 3, 17], + [1964, 4, 29], + [1999, 5, 18], + [2000, 6, 21], + [2019, 7, 4], + [2020, 8, 31], + [1956, 9, 10], + [2010, 10, 10], + [1982, 11, 30], + [1960, 12, 19], + ['=YEAR(TODAY())', '=MONTH(TODAY())', '=DAY(TODAY())'], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=WEEKDAY(D' . $row . ')'); + $worksheet->setCellValue('G' . $row, '=WEEKDAY(D' . $row . ', 2)'); +} +$worksheet->getStyle('E1:E' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log(sprintf( + 'Weekday is: %d (1-7 = Sun-Sat)', + $worksheet->getCell('F' . $row)->getCalculatedValue() + )); + $helper->log(sprintf( + 'Weekday is: %d (1-7 = Mon-Sun)', + $worksheet->getCell('G' . $row)->getCalculatedValue() + )); +} diff --git a/samples/Calculations/DateTime/WEEKNUM.php b/samples/Calculations/DateTime/WEEKNUM.php new file mode 100644 index 00000000..1d4c4a12 --- /dev/null +++ b/samples/Calculations/DateTime/WEEKNUM.php @@ -0,0 +1,52 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 2, 14], + [1936, 3, 17], + [1964, 4, 29], + [1999, 5, 18], + [2000, 6, 21], + [2019, 7, 4], + [2020, 8, 31], + [1956, 9, 10], + [2010, 10, 10], + [1982, 11, 30], + [1960, 12, 19], + ['=YEAR(TODAY())', '=MONTH(TODAY())', '=DAY(TODAY())'], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=WEEKNUM(D' . $row . ')'); + $worksheet->setCellValue('G' . $row, '=WEEKNUM(D' . $row . ', 21)'); +} +$worksheet->getStyle('E1:E' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('System 1 Week number is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); + $helper->log('System 2 (ISO-8601) Week number is: ' . $worksheet->getCell('G' . $row)->getCalculatedValue()); +} diff --git a/samples/Calculations/DateTime/YEAR.php b/samples/Calculations/DateTime/YEAR.php new file mode 100644 index 00000000..f7bfa6ea --- /dev/null +++ b/samples/Calculations/DateTime/YEAR.php @@ -0,0 +1,50 @@ +titles($category, $functionName, $description); + +// Create new PhpSpreadsheet object +$spreadsheet = new Spreadsheet(); +$worksheet = $spreadsheet->getActiveSheet(); + +// Add some data +$testDates = [ + [1900, 1, 1], + [1904, 2, 14], + [1936, 3, 17], + [1964, 4, 29], + [1999, 5, 18], + [2000, 6, 21], + [2019, 7, 4], + [2020, 8, 31], + [1956, 9, 10], + [2010, 10, 10], + [1982, 11, 30], + [1960, 12, 19], + ['=YEAR(TODAY())', '=MONTH(TODAY())', '=DAY(TODAY())'], +]; +$testDateCount = count($testDates); + +$worksheet->fromArray($testDates, null, 'A1', true); + +for ($row = 1; $row <= $testDateCount; ++$row) { + $worksheet->setCellValue('D' . $row, '=DATE(A' . $row . ',B' . $row . ',C' . $row . ')'); + $worksheet->setCellValue('E' . $row, '=D' . $row); + $worksheet->setCellValue('F' . $row, '=YEAR(D' . $row . ')'); +} +$worksheet->getStyle('E1:E' . $testDateCount) + ->getNumberFormat() + ->setFormatCode('yyyy-mm-dd'); + +// Test the formulae +for ($row = 1; $row <= $testDateCount; ++$row) { + $helper->log(sprintf('(E%d): %s', $row, $worksheet->getCell('E' . $row)->getFormattedValue())); + $helper->log('Year is: ' . $worksheet->getCell('F' . $row)->getCalculatedValue()); +} diff --git a/src/PhpSpreadsheet/Helper/Sample.php b/src/PhpSpreadsheet/Helper/Sample.php index aeb2bea6..9f7563d6 100644 --- a/src/PhpSpreadsheet/Helper/Sample.php +++ b/src/PhpSpreadsheet/Helper/Sample.php @@ -187,8 +187,8 @@ class Sample { $this->log(sprintf('%s Functions:', $category)); $description === null - ? $this->log(sprintf('%s()', rtrim($functionName, '()'))) - : $this->log(sprintf('%s() - %s.', rtrim($functionName, '()'), rtrim($description, '.'))); + ? $this->log(sprintf('Function: %s()', rtrim($functionName, '()'))) + : $this->log(sprintf('Function: %s() - %s.', rtrim($functionName, '()'), rtrim($description, '.'))); } public function displayGrid(array $matrix): void