Skip to content

Commit

Permalink
Merge pull request #3855 from oleibman/issue3847
Browse files Browse the repository at this point in the history
Partial Support of Fill Handles
  • Loading branch information
oleibman authored Jan 10, 2024
2 parents 085e443 + 656efb9 commit 6f36db8
Show file tree
Hide file tree
Showing 3 changed files with 113 additions and 1 deletion.
3 changes: 2 additions & 1 deletion CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,8 @@ and this project adheres to [Semantic Versioning](https://semver.org).
- Check if Coordinate is Inside Range [PR #3779](https://github.com/PHPOffice/PhpSpreadsheet/pull/3779)
- Flipping Images [Issue #731](https://github.com/PHPOffice/PhpSpreadsheet/issues/731) [PR #3801](https://github.com/PHPOffice/PhpSpreadsheet/pull/3801)
- Chart Dynamic Title and Font Properties [Issue #3797](https://github.com/PHPOffice/PhpSpreadsheet/issues/3797) [PR #3800](https://github.com/PHPOffice/PhpSpreadsheet/pull/3800)
- Chart Axis Display Units and Logarithmic Scale. [Issue #3833](https://github.com/PHPOffice/PhpSpreadsheet/pull/3833) [PR #3836](https://github.com/PHPOffice/PhpSpreadsheet/pull/3836)
- Chart Axis Display Units and Logarithmic Scale. [Issue #3833](https://github.com/PHPOffice/PhpSpreadsheet/issues/3833) [PR #3836](https://github.com/PHPOffice/PhpSpreadsheet/pull/3836)
- Partial Support of Fill Handles. [Discussion #3847](https://github.com/PHPOffice/PhpSpreadsheet/discussions/3847) [PR #3855](https://github.com/PHPOffice/PhpSpreadsheet/pull/3855)

### Changed

Expand Down
26 changes: 26 additions & 0 deletions src/PhpSpreadsheet/Worksheet/Worksheet.php
Original file line number Diff line number Diff line change
Expand Up @@ -3587,4 +3587,30 @@ public function setBackgroundImage(string $backgroundImage): self

return $this;
}

/**
* Copy cells, adjusting relative cell references in formulas.
* Acts similarly to Excel "fill handle" feature.
*
* @param string $fromCell Single source cell, e.g. C3
* @param string $toCells Single cell or cell range, e.g. C4 or C4:C10
* @param bool $copyStyle Copy styles as well as values, defaults to true
*/
public function copyCells(string $fromCell, string $toCells, bool $copyStyle = true): void
{
$toArray = Coordinate::extractAllCellReferencesInRange($toCells);
$value = $this->getCell($fromCell)->getValue();
$style = $this->getStyle($fromCell)->exportArray();
$fromIndexes = Coordinate::indexesFromString($fromCell);
$referenceHelper = ReferenceHelper::getInstance();
foreach ($toArray as $destination) {
if ($destination !== $fromCell) {
$toIndexes = Coordinate::indexesFromString($destination);
$this->getCell($destination)->setValue($referenceHelper->updateFormulaReferences($value, 'A1', $toIndexes[0] - $fromIndexes[0], $toIndexes[1] - $fromIndexes[1]));
if ($copyStyle) {
$this->getCell($destination)->getStyle()->applyFromArray($style);
}
}
}
}
}
85 changes: 85 additions & 0 deletions tests/PhpSpreadsheetTests/Worksheet/CopyCellsTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
<?php

declare(strict_types=1);

namespace PhpOffice\PhpSpreadsheetTests\Worksheet;

use PhpOffice\PhpSpreadsheet\Exception as SpreadsheetException;
use PhpOffice\PhpSpreadsheet\Spreadsheet;
use PHPUnit\Framework\TestCase;

class CopyCellsTest extends TestCase
{
public function testCopyCells(): void
{
$spreadsheet = new Spreadsheet();
$sheet = $spreadsheet->getActiveSheet();
$sheet->fromArray(
[
['hello1', 'goodbye1', 'neither1', 'constant'],
['hello2', 'goodbye2', 'neither2'],
['hello3', 'goodbye3', 'neither3'],
['hello4', 'goodbye4', 'neither4'],
['hello5', 'goodbye5', 'neither5'],
],
);
$sheet->getCell('E3')->setValue('=A1&B1');
$sheet->getStyle('E3')->getFont()->setBold(true);
$sheet->copyCells('E3', 'E3:F7');
$result1 = $sheet->rangeToArray('E3:F7', null, false, false);
$expected1 = [
['=A1&B1', '=B1&C1'],
['=A2&B2', '=B2&C2'],
['=A3&B3', '=B3&C3'],
['=A4&B4', '=B4&C4'],
['=A5&B5', '=B5&C5'],
];
self::assertSame($expected1, $result1);
self::assertSame('goodbye3neither3', $sheet->getCell('F5')->getCalculatedValue());
self::assertTrue($sheet->getCell('F5')->getStyle()->getFont()->getBold());

$sheet->getCell('E14')->setValue('=A5&$D$1');
$sheet->copyCells('E14', 'E10:E14');
$result2 = $sheet->rangeToArray('E10:E14', null, false, false);
$expected2 = [
['=A1&$D$1'],
['=A2&$D$1'],
['=A3&$D$1'],
['=A4&$D$1'],
['=A5&$D$1'],
];
self::assertSame($expected2, $result2);
self::assertSame('hello4constant', $sheet->getCell('E13')->getCalculatedValue());

$sheet->getCell('I3')->setValue('=A1&$B1');
$sheet->getStyle('I3')->getFont()->setItalic(true);
$sheet->copyCells('I3', 'I3:J7', false);
$result3 = $sheet->rangeToArray('I3:J7', null, false, false);
$expected3 = [
['=A1&$B1', '=B1&$B1'],
['=A2&$B2', '=B2&$B2'],
['=A3&$B3', '=B3&$B3'],
['=A4&$B4', '=B4&$B4'],
['=A5&$B5', '=B5&$B5'],
];
self::assertSame($expected3, $result3);
self::assertSame('hello2goodbye2', $sheet->getCell('I4')->getCalculatedValue());
self::assertFalse($sheet->getCell('I5')->getStyle()->getFont()->getItalic());

try {
$sheet->copyCells('invalid', 'Z1:Z10');
self::fail('Did not receive expected exception');
} catch (SpreadsheetException $e) {
self::assertStringContainsString('Invalid cell coordinate', $e->getMessage());
}

try {
$sheet->copyCells('A1', 'invalid');
self::fail('Did not receive expected exception');
} catch (SpreadsheetException $e) {
self::assertStringContainsString('Column string index', $e->getMessage());
}

$spreadsheet->disconnectWorksheets();
}
}

0 comments on commit 6f36db8

Please sign in to comment.