Skip to content

Commit

Permalink
Consistent stringFromColumnIndex() and columnIndexFromString()
Browse files Browse the repository at this point in the history
Column indexes are always based on 1 everywhere in PhpSpreadsheet.
This is consistent with rows starting at 1, as well as Excel
function `COLUMN()`. It should also make it easier to reason about
columns and rows and remove any doubts whether a specific method is
expecting 0 based or 1 based indexes.

Fixes #273
Fixes PHPOffice/PHPExcel#307
Fixes PHPOffice/PHPExcel#476
  • Loading branch information
PowerKiKi committed Nov 26, 2017
1 parent e0150fd commit 8d76020
Show file tree
Hide file tree
Showing 32 changed files with 425 additions and 352 deletions.
2 changes: 2 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -29,6 +29,8 @@ and this project adheres to [Semantic Versioning](http://semver.org/).

### BREAKING CHANGE

- Extracted coordinate method to dedicate class [migration guide](./docs/topics/migration-from-PHPExcel.md).
- Column indexes are based on 1, see the [migration guide](./docs/topics/migration-from-PHPExcel.md).
- Standardization of array keys used for style, see the [migration guide](./docs/topics/migration-from-PHPExcel.md).
- Easier usage of PDF writers, and other custom readers and writers, see the [migration guide](./docs/topics/migration-from-PHPExcel.md).
- Easier usage of chart renderers, see the [migration guide](./docs/topics/migration-from-PHPExcel.md).
Expand Down
22 changes: 8 additions & 14 deletions docs/topics/accessing-cells.md
Original file line number Diff line number Diff line change
Expand Up @@ -261,8 +261,7 @@ the cell's `getFormattedValue()` method.

``` php
// Get the value fom cell A6
$cellValue = $spreadsheet->getActiveSheet()->getCell('A6')
->getFormattedValue();
$cellValue = $spreadsheet->getActiveSheet()->getCell('A6')->getFormattedValue();
```

## Setting a cell value by column and row
Expand All @@ -281,22 +280,20 @@ than from `1`.
## Retrieving a cell value by column and row

To retrieve the value of a cell, the cell should first be retrieved from
the worksheet using the getCellByColumnAndRow method. A cell’s value can
the worksheet using the `getCellByColumnAndRow()` method. A cell’s value can
be read again using the following line of code:

``` php
// Get the value fom cell B5
$cellValue = $spreadsheet->getActiveSheet()->getCellByColumnAndRow(1, 5)
->getValue();
$cellValue = $spreadsheet->getActiveSheet()->getCellByColumnAndRow(2, 5)->getValue();
```

If you need the calculated value of a cell, use the following code. This
is further explained in .

``` php
// Get the value fom cell A4
$cellValue = $spreadsheet->getActiveSheet()->getCellByColumnAndRow(0, 4)
->getCalculatedValue();
$cellValue = $spreadsheet->getActiveSheet()->getCellByColumnAndRow(1, 4)->getCalculatedValue();
```

## Retrieving a range of cell values to an array
Expand Down Expand Up @@ -374,8 +371,7 @@ One can use the possibility to access cell values by column and row
index like (0,1) instead of 'A1' for reading and writing cell values in
loops.

Note: In PhpSpreadsheet column index is 0-based while row index is
1-based. That means 'A1' \~ (0,1)
Note: In PhpSpreadsheet column index and row index are 1-based. That means `'A1'` ~ `[1, 1]`

Below is an example where we read all the values in a worksheet and
display them in a table.
Expand All @@ -394,11 +390,9 @@ $highestColumnIndex = \PhpOffice\PhpSpreadsheet\Cell\Cell::columnIndexFromString
echo '<table>' . "\n";
for ($row = 1; $row <= $highestRow; ++$row) {
echo '<tr>' . PHP_EOL;
for ($col = 0; $col <= $highestColumnIndex; ++$col) {
echo '<td>' .
$worksheet->getCellByColumnAndRow($col, $row)
->getValue() .
'</td>' . PHP_EOL;
for ($col = 1; $col <= $highestColumnIndex; ++$col) {
$value = $worksheet->getCellByColumnAndRow($col, $row)->getValue();
echo '<td>' . $value . '</td>' . PHP_EOL;
}
echo '</tr>' . PHP_EOL;
}
Expand Down
63 changes: 63 additions & 0 deletions docs/topics/migration-from-PHPExcel.md
Original file line number Diff line number Diff line change
Expand Up @@ -363,3 +363,66 @@ $style = [
],
];
```

### Dedicated class to manipulate coordinates

Methods to manipulate coordinates that used to exists in `PHPExcel_Cell` were extracted
to a dedicated new class `\PhpOffice\PhpSpreadsheet\Cell\Coordinate`. The methods are:

- `absoluteCoordinate()`
- `absoluteReference()`
- `buildRange()`
- `columnIndexFromString()`
- `coordinateFromString()`
- `extractAllCellReferencesInRange()`
- `getRangeBoundaries()`
- `mergeRangesInCollection()`
- `rangeBoundaries()`
- `rangeDimension()`
- `splitRange()`
- `stringFromColumnIndex()`

### Column index based on 1

Column indexes are now based on 1. So column `A` is the index `1`. This is consistent
with rows starting at 1 and Excel function `COLUMN()` that returns `1` for column `A`.
So the code must be adapted with something like:

```php
// Before
$cell = $worksheet->getCellByColumnAndRow($column, $row);

for ($column = 0; $column < $max; $column++) {
$worksheet->setCellValueByColumnAndRow($column, $row, 'value ' . $column);
}

// After
$cell = $worksheet->getCellByColumnAndRow($column + 1, $row);

for ($column = 1; $column <= $max; $column++) {
$worksheet->setCellValueByColumnAndRow($column, $row, 'value ' . $column);
}
```

All the following methods are affected:

- `PHPExcel_Worksheet::cellExistsByColumnAndRow()`
- `PHPExcel_Worksheet::freezePaneByColumnAndRow()`
- `PHPExcel_Worksheet::getCellByColumnAndRow()`
- `PHPExcel_Worksheet::getColumnDimensionByColumn()`
- `PHPExcel_Worksheet::getCommentByColumnAndRow()`
- `PHPExcel_Worksheet::getStyleByColumnAndRow()`
- `PHPExcel_Worksheet::insertNewColumnBeforeByIndex()`
- `PHPExcel_Worksheet::mergeCellsByColumnAndRow()`
- `PHPExcel_Worksheet::protectCellsByColumnAndRow()`
- `PHPExcel_Worksheet::removeColumnByIndex()`
- `PHPExcel_Worksheet::setAutoFilterByColumnAndRow()`
- `PHPExcel_Worksheet::setBreakByColumnAndRow()`
- `PHPExcel_Worksheet::setCellValueByColumnAndRow()`
- `PHPExcel_Worksheet::setCellValueExplicitByColumnAndRow()`
- `PHPExcel_Worksheet::setSelectedCellByColumnAndRow()`
- `PHPExcel_Worksheet::stringFromColumnIndex()`
- `PHPExcel_Worksheet::unmergeCellsByColumnAndRow()`
- `PHPExcel_Worksheet::unprotectCellsByColumnAndRow()`
- `PHPExcel_Worksheet_PageSetup::addPrintAreaByColumnAndRow()`
- `PHPExcel_Worksheet_PageSetup::setPrintAreaByColumnAndRow()`
2 changes: 1 addition & 1 deletion samples/Basic/40_Duplicate_style.php
Original file line number Diff line number Diff line change
Expand Up @@ -20,7 +20,7 @@

$helper->log('Add data (begin)');
$t = microtime(true);
for ($col = 0; $col < 50; ++$col) {
for ($col = 1; $col <= 50; ++$col) {
for ($row = 0; $row < 100; ++$row) {
$str = ($row + $col);
$style = $styles[$row % 10];
Expand Down
4 changes: 2 additions & 2 deletions src/PhpSpreadsheet/Calculation/Calculation.php
Original file line number Diff line number Diff line change
Expand Up @@ -3496,7 +3496,7 @@ private function processTokenStack($tokens, $cellID = null, Cell $pCell = null)
$oCol[] = Coordinate::columnIndexFromString($oCR[0]) - 1;
$oRow[] = $oCR[1];
}
$cellRef = Coordinate::stringFromColumnIndex(min($oCol)) . min($oRow) . ':' . Coordinate::stringFromColumnIndex(max($oCol)) . max($oRow);
$cellRef = Coordinate::stringFromColumnIndex(min($oCol) + 1) . min($oRow) . ':' . Coordinate::stringFromColumnIndex(max($oCol) + 1) . max($oRow);
if ($pCellParent !== null) {
$cellValue = $this->extractCellRange($cellRef, $this->spreadsheet->getSheetByName($sheet1), false);
} else {
Expand Down Expand Up @@ -3569,7 +3569,7 @@ private function processTokenStack($tokens, $cellID = null, Cell $pCell = null)
$cellIntersect[$row] = array_intersect_key($operand1[$row], $operand2[$row]);
}
}
$cellRef = Coordinate::stringFromColumnIndex(min($oCol)) . min($oRow) . ':' . Coordinate::stringFromColumnIndex(max($oCol)) . max($oRow);
$cellRef = Coordinate::stringFromColumnIndex(min($oCol) + 1) . min($oRow) . ':' . Coordinate::stringFromColumnIndex(max($oCol) + 1) . max($oRow);
$this->debugLog->writeDebugLog('Evaluation Result is ', $this->showTypeDetails($cellIntersect));
$stack->push('Value', $cellIntersect, $cellRef);

Expand Down
6 changes: 3 additions & 3 deletions src/PhpSpreadsheet/Calculation/LookupRef.php
Original file line number Diff line number Diff line change
Expand Up @@ -53,7 +53,7 @@ public static function cellAddress($row, $column, $relativity = 1, $referenceSty
}
if ((!is_bool($referenceStyle)) || $referenceStyle) {
$rowRelative = $columnRelative = '$';
$column = Coordinate::stringFromColumnIndex($column - 1);
$column = Coordinate::stringFromColumnIndex($column);
if (($relativity == 2) || ($relativity == 4)) {
$columnRelative = '';
}
Expand Down Expand Up @@ -399,7 +399,7 @@ public static function OFFSET($cellAddress = null, $rows = 0, $columns = 0, $hei
} else {
$endCellColumn += $columns;
}
$startCellColumn = Coordinate::stringFromColumnIndex($startCellColumn);
$startCellColumn = Coordinate::stringFromColumnIndex($startCellColumn + 1);

if (($height != null) && (!is_object($height))) {
$endCellRow = $startCellRow + $height - 1;
Expand All @@ -410,7 +410,7 @@ public static function OFFSET($cellAddress = null, $rows = 0, $columns = 0, $hei
if (($endCellRow <= 0) || ($endCellColumn < 0)) {
return Functions::REF();
}
$endCellColumn = Coordinate::stringFromColumnIndex($endCellColumn);
$endCellColumn = Coordinate::stringFromColumnIndex($endCellColumn + 1);

$cellAddress = $startCellColumn . $startCellRow;
if (($startCellColumn != $endCellColumn) || ($startCellRow != $endCellRow)) {
Expand Down
14 changes: 10 additions & 4 deletions src/PhpSpreadsheet/Cell/Coordinate.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,12 @@

use PhpOffice\PhpSpreadsheet\Exception;

/**
* Helper class to manipulate cell coordinates.
*
* Columns indexes and rows are always based on 1, **not** on 0. This match the behavior
* that Excel users are used to, and also match the Excel functions `COLUMN()` and `ROW()`.
*/
abstract class Coordinate
{
/**
Expand Down Expand Up @@ -240,7 +246,7 @@ public static function getRangeBoundaries($pRange)
*
* @param string $pString eg 'A'
*
* @return int Column index (base 1 !!!)
* @return int Column index (A = 1)
*/
public static function columnIndexFromString($pString)
{
Expand Down Expand Up @@ -284,9 +290,9 @@ public static function columnIndexFromString($pString)
}

/**
* String from columnindex.
* String from column index.
*
* @param int $columnIndex Column index (A = 0)
* @param int $columnIndex Column index (A = 1)
*
* @return string
*/
Expand All @@ -295,7 +301,7 @@ public static function stringFromColumnIndex($columnIndex)
static $indexCache = [];

if (!isset($indexCache[$columnIndex])) {
$indexValue = $columnIndex + 1;
$indexValue = $columnIndex;
$base26 = null;
do {
$characterValue = ($indexValue % 26) ?: 26;
Expand Down
2 changes: 1 addition & 1 deletion src/PhpSpreadsheet/Collection/Cells.php
Original file line number Diff line number Diff line change
Expand Up @@ -248,7 +248,7 @@ public function getHighestColumn($row = null)
$columnList[] = Coordinate::columnIndexFromString($c);
}

return Coordinate::stringFromColumnIndex(max($columnList) - 1);
return Coordinate::stringFromColumnIndex(max($columnList) + 1);
}

/**
Expand Down
2 changes: 1 addition & 1 deletion src/PhpSpreadsheet/Reader/Csv.php
Original file line number Diff line number Diff line change
Expand Up @@ -251,7 +251,7 @@ public function listWorksheetInfo($pFilename)
$worksheetInfo[0]['lastColumnIndex'] = max($worksheetInfo[0]['lastColumnIndex'], count($rowData) - 1);
}

$worksheetInfo[0]['lastColumnLetter'] = Coordinate::stringFromColumnIndex($worksheetInfo[0]['lastColumnIndex']);
$worksheetInfo[0]['lastColumnLetter'] = Coordinate::stringFromColumnIndex($worksheetInfo[0]['lastColumnIndex'] + 1);
$worksheetInfo[0]['totalColumns'] = $worksheetInfo[0]['lastColumnIndex'] + 1;

// Close file
Expand Down
16 changes: 8 additions & 8 deletions src/PhpSpreadsheet/Reader/Gnumeric.php
Original file line number Diff line number Diff line change
Expand Up @@ -138,7 +138,7 @@ public function listWorksheetInfo($pFilename)
break;
}
}
$tmpInfo['lastColumnLetter'] = Coordinate::stringFromColumnIndex($tmpInfo['lastColumnIndex']);
$tmpInfo['lastColumnLetter'] = Coordinate::stringFromColumnIndex($tmpInfo['lastColumnIndex'] + 1);
$worksheetInfo[] = $tmpInfo;
}
}
Expand Down Expand Up @@ -394,7 +394,7 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
$maxCol = $column;
}

$column = Coordinate::stringFromColumnIndex($column);
$column = Coordinate::stringFromColumnIndex($column + 1);

// Read cell?
if ($this->getReadFilter() !== null) {
Expand Down Expand Up @@ -472,11 +472,11 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
$styleAttributes = $styleRegion->attributes();
if (($styleAttributes['startRow'] <= $maxRow) &&
($styleAttributes['startCol'] <= $maxCol)) {
$startColumn = Coordinate::stringFromColumnIndex((int) $styleAttributes['startCol']);
$startColumn = Coordinate::stringFromColumnIndex((int) $styleAttributes['startCol'] + 1);
$startRow = $styleAttributes['startRow'] + 1;

$endColumn = ($styleAttributes['endCol'] > $maxCol) ? $maxCol : (int) $styleAttributes['endCol'];
$endColumn = Coordinate::stringFromColumnIndex($endColumn);
$endColumn = Coordinate::stringFromColumnIndex($endColumn + 1);
$endRow = ($styleAttributes['endRow'] > $maxRow) ? $maxRow : $styleAttributes['endRow'];
$endRow += 1;
$cellRange = $startColumn . $startRow . ':' . $endColumn . $endRow;
Expand Down Expand Up @@ -718,19 +718,19 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
$hidden = ((isset($columnAttributes['Hidden'])) && ($columnAttributes['Hidden'] == '1')) ? true : false;
$columnCount = (isset($columnAttributes['Count'])) ? $columnAttributes['Count'] : 1;
while ($c < $column) {
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c))->setWidth($defaultWidth);
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c + 1))->setWidth($defaultWidth);
++$c;
}
while (($c < ($column + $columnCount)) && ($c <= $maxCol)) {
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c))->setWidth($columnWidth);
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c + 1))->setWidth($columnWidth);
if ($hidden) {
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c))->setVisible(false);
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c + 1))->setVisible(false);
}
++$c;
}
}
while ($c <= $maxCol) {
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c))->setWidth($defaultWidth);
$spreadsheet->getActiveSheet()->getColumnDimension(Coordinate::stringFromColumnIndex($c + 1))->setWidth($defaultWidth);
++$c;
}
}
Expand Down
4 changes: 2 additions & 2 deletions src/PhpSpreadsheet/Reader/Ods.php
Original file line number Diff line number Diff line change
Expand Up @@ -215,7 +215,7 @@ public function listWorksheetInfo($pFilename)

$tmpInfo['totalColumns'] = max($tmpInfo['totalColumns'], $currCells);
$tmpInfo['lastColumnIndex'] = $tmpInfo['totalColumns'] - 1;
$tmpInfo['lastColumnLetter'] = Coordinate::stringFromColumnIndex($tmpInfo['lastColumnIndex']);
$tmpInfo['lastColumnLetter'] = Coordinate::stringFromColumnIndex($tmpInfo['lastColumnIndex'] + 1);
$worksheetInfo[] = $tmpInfo;
}
}
Expand Down Expand Up @@ -707,7 +707,7 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
$columnIndex += (int) $cellData->getAttributeNS($tableNs, 'number-columns-spanned');
$columnIndex -= 2;

$columnTo = Coordinate::stringFromColumnIndex($columnIndex);
$columnTo = Coordinate::stringFromColumnIndex($columnIndex + 1);
}

$rowTo = $rowID;
Expand Down
16 changes: 8 additions & 8 deletions src/PhpSpreadsheet/Reader/Slk.php
Original file line number Diff line number Diff line change
Expand Up @@ -161,7 +161,7 @@ public function listWorksheetInfo($pFilename)
}
}

$worksheetInfo[0]['lastColumnLetter'] = Coordinate::stringFromColumnIndex($worksheetInfo[0]['lastColumnIndex']);
$worksheetInfo[0]['lastColumnLetter'] = Coordinate::stringFromColumnIndex($worksheetInfo[0]['lastColumnIndex'] + 1);
$worksheetInfo[0]['totalColumns'] = $worksheetInfo[0]['lastColumnIndex'] + 1;

// Close file
Expand Down Expand Up @@ -337,7 +337,7 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
if ($columnReference[0] == '[') {
$columnReference = $column + trim($columnReference, '[]');
}
$A1CellReference = Coordinate::stringFromColumnIndex($columnReference - 1) . $rowReference;
$A1CellReference = Coordinate::stringFromColumnIndex($columnReference) . $rowReference;

$value = substr_replace($value, $A1CellReference, $cellReference[0][1], strlen($cellReference[0][0]));
}
Expand All @@ -351,7 +351,7 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
break;
}
}
$columnLetter = Coordinate::stringFromColumnIndex($column - 1);
$columnLetter = Coordinate::stringFromColumnIndex($column);
$cellData = Calculation::unwrapResult($cellData);

// Set cell value
Expand Down Expand Up @@ -419,22 +419,22 @@ public function loadIntoExisting($pFilename, Spreadsheet $spreadsheet)
}
}
if (($formatStyle > '') && ($column > '') && ($row > '')) {
$columnLetter = Coordinate::stringFromColumnIndex($column - 1);
$columnLetter = Coordinate::stringFromColumnIndex($column);
if (isset($this->formats[$formatStyle])) {
$spreadsheet->getActiveSheet()->getStyle($columnLetter . $row)->applyFromArray($this->formats[$formatStyle]);
}
}
if ((!empty($styleData)) && ($column > '') && ($row > '')) {
$columnLetter = Coordinate::stringFromColumnIndex($column - 1);
$columnLetter = Coordinate::stringFromColumnIndex($column);
$spreadsheet->getActiveSheet()->getStyle($columnLetter . $row)->applyFromArray($styleData);
}
if ($columnWidth > '') {
if ($startCol == $endCol) {
$startCol = Coordinate::stringFromColumnIndex($startCol - 1);
$startCol = Coordinate::stringFromColumnIndex($startCol);
$spreadsheet->getActiveSheet()->getColumnDimension($startCol)->setWidth($columnWidth);
} else {
$startCol = Coordinate::stringFromColumnIndex($startCol - 1);
$endCol = Coordinate::stringFromColumnIndex($endCol - 1);
$startCol = Coordinate::stringFromColumnIndex($startCol);
$endCol = Coordinate::stringFromColumnIndex($endCol);
$spreadsheet->getActiveSheet()->getColumnDimension($startCol)->setWidth($columnWidth);
do {
$spreadsheet->getActiveSheet()->getColumnDimension(++$startCol)->setWidth($columnWidth);
Expand Down
Loading

0 comments on commit 8d76020

Please sign in to comment.