From feffb76944e631475f986785a1d320a146d5a3dd Mon Sep 17 00:00:00 2001 From: aswinkumar863 Date: Sun, 3 Apr 2022 18:27:38 +0530 Subject: [PATCH] Added Column Formula Option to add column formula that applied automatically for any new rows added to the table range --- samples/Table/03_Column_Formula.php | 72 +++++++++++++++++++ src/PhpSpreadsheet/Worksheet/Table/Column.php | 29 ++++++++ src/PhpSpreadsheet/Writer/Xlsx/Table.php | 4 ++ .../Worksheet/Table/ColumnTest.php | 5 ++ 4 files changed, 110 insertions(+) create mode 100644 samples/Table/03_Column_Formula.php diff --git a/samples/Table/03_Column_Formula.php b/samples/Table/03_Column_Formula.php new file mode 100644 index 00000000..e8ae5d99 --- /dev/null +++ b/samples/Table/03_Column_Formula.php @@ -0,0 +1,72 @@ +log('Create new Spreadsheet object'); +$spreadsheet = new Spreadsheet(); + +// Set document properties +$helper->log('Set document properties'); +$spreadsheet->getProperties()->setCreator('aswinkumar863') + ->setLastModifiedBy('aswinkumar863') + ->setTitle('PhpSpreadsheet Table Test Document') + ->setSubject('PhpSpreadsheet Table Test Document') + ->setDescription('Test document for PhpSpreadsheet, generated using PHP classes.') + ->setKeywords('office PhpSpreadsheet php') + ->setCategory('Table'); + +// Create the worksheet +$helper->log('Add data'); + +$spreadsheet->setActiveSheetIndex(0); + +$columnFormula = '=SUM(Sales_Data[[#This Row],[Q1]:[Q4]])'; + +$dataArray = [ + ['Year', 'Country', 'Q1', 'Q2', 'Q3', 'Q4', 'Sales'], + [2010, 'Belgium', 380, 390, 420, 460, $columnFormula], + [2010, 'France', 510, 490, 460, 590, $columnFormula], + [2010, 'Germany', 720, 680, 640, 660, $columnFormula], + [2010, 'Italy', 440, 410, 420, 450, $columnFormula], + [2010, 'Spain', 510, 490, 470, 420, $columnFormula], + [2010, 'UK', 690, 610, 620, 600, $columnFormula], + [2010, 'United States', 790, 730, 860, 850, $columnFormula], + [2011, 'Belgium', 400, 350, 450, 500, $columnFormula], + [2011, 'France', 620, 650, 415, 570, $columnFormula], + [2011, 'Germany', 680, 620, 710, 690, $columnFormula], + [2011, 'Italy', 430, 370, 350, 335, $columnFormula], + [2011, 'Spain', 460, 390, 430, 415, $columnFormula], + [2011, 'UK', 720, 650, 580, 510, $columnFormula], + [2011, 'United States', 800, 700, 900, 950, $columnFormula], +]; + +$spreadsheet->getActiveSheet()->fromArray($dataArray, null, 'A1'); + +// Create Table +$helper->log('Create Table'); +$table = new Table(); +$table->setName('Sales_Data'); +$table->setRange('A1:G15'); + +// Set Column Formula +$table->getColumn('G')->setColumnFormula($columnFormula); + +// Add Table to Worksheet +$helper->log('Add Table to Worksheet'); +$spreadsheet->getActiveSheet()->addTable($table); + +// Save +$path = $helper->getFilename(__FILE__); +$writer = IOFactory::createWriter($spreadsheet, 'Xlsx'); + +// Disable precalculation to add table's total row +$writer->setPreCalculateFormulas(false); +$callStartTime = microtime(true); +$writer->save($path); +$helper->logWrite($writer, $path, $callStartTime); +$helper->logEndingNotes(); diff --git a/src/PhpSpreadsheet/Worksheet/Table/Column.php b/src/PhpSpreadsheet/Worksheet/Table/Column.php index d9b87d80..06284c67 100644 --- a/src/PhpSpreadsheet/Worksheet/Table/Column.php +++ b/src/PhpSpreadsheet/Worksheet/Table/Column.php @@ -41,6 +41,13 @@ class Column */ private $totalsRowFormula; + /** + * Column Formula. + * + * @var string + */ + private $columnFormula; + /** * Table. * @@ -178,6 +185,28 @@ class Column return $this; } + /** + * Get column Formula. + * + * @return string + */ + public function getColumnFormula() + { + return $this->columnFormula; + } + + /** + * Set column Formula. + * + * @return $this + */ + public function setColumnFormula(string $columnFormula) + { + $this->columnFormula = $columnFormula; + + return $this; + } + /** * Get this Column's Table. * diff --git a/src/PhpSpreadsheet/Writer/Xlsx/Table.php b/src/PhpSpreadsheet/Writer/Xlsx/Table.php index e7adfd3c..be9f5183 100644 --- a/src/PhpSpreadsheet/Writer/Xlsx/Table.php +++ b/src/PhpSpreadsheet/Writer/Xlsx/Table.php @@ -86,6 +86,10 @@ class Table extends WriterPart $objWriter->writeAttribute('totalsRowFunction', $column->getTotalsRowFunction()); } } + if ($column->getColumnFormula()) { + $objWriter->writeElement('calculatedColumnFormula', $column->getColumnFormula()); + } + $objWriter->endElement(); } $objWriter->endElement(); diff --git a/tests/PhpSpreadsheetTests/Worksheet/Table/ColumnTest.php b/tests/PhpSpreadsheetTests/Worksheet/Table/ColumnTest.php index 195d6e41..c7edd86a 100644 --- a/tests/PhpSpreadsheetTests/Worksheet/Table/ColumnTest.php +++ b/tests/PhpSpreadsheetTests/Worksheet/Table/ColumnTest.php @@ -74,6 +74,11 @@ class ColumnTest extends SetupTeardown $result = $column->setTotalsRowFunction($function); self::assertInstanceOf(Column::class, $result); self::assertEquals($function, $column->getTotalsRowFunction()); + + $formula = '=SUM(Sales_Data[[#This Row],[Q1]:[Q4]])'; + $result = $column->setColumnFormula($formula); + self::assertInstanceOf(Column::class, $result); + self::assertEquals($formula, $column->getColumnFormula()); } public function testTable(): void