Skip to content

Calculation engine array formulae initial work #2539

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Closed
wants to merge 115 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
115 commits
Select commit Hold shift + click to select a range
8156ed9
First steps to handling array formulae with the Xlsx Reader and Writer
Jan 30, 2022
39a6c29
Set formula attributes datatype in Cell
Jan 30, 2022
73e7ee0
Write correct cell area ref when saving array formulae in cells for X…
Jan 30, 2022
6a51ad4
Basic Read/Write test for an array function; verify that formula attr…
Jan 30, 2022
1d941b4
Initial work on setting an array formula through code, and populating…
Jan 31, 2022
69436d3
phpcs fixes
Jan 31, 2022
5d258f1
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Jan 31, 2022
d2435cd
Ensure that a basic metadata file containing a cell metadata definiti…
Feb 1, 2022
9f3db99
Ensure that our array result dimensions match the specified array for…
Feb 2, 2022
1fa690c
Provide a method to easily access the array formula range for a cell …
Feb 2, 2022
beb1e8f
Update array formula ranges when inserting/deleting rows/columns
Feb 2, 2022
9bfc4be
Stubs for MS pseudo-functions used to handle the Spillage (`ANCHORARR…
Feb 2, 2022
ceb1c04
Initial work implementing the SINGLE() and ANCHORARRAY() pseudo-funct…
Feb 2, 2022
54d49ed
Unit tests for pseudo-functions
Feb 3, 2022
12ddc9e
General fixes for array functions with partial-range
Feb 3, 2022
7d84faf
Updates to function lists
Feb 3, 2022
abf4f9c
regenerate phpstan baseline (it is smaller, honest)
Feb 3, 2022
c84e334
Update documentation with details of array formula handling, and the …
Feb 3, 2022
66e63eb
Modify ABS() function to handle arrays, with appropriate unit tests
Feb 3, 2022
3cec90d
Minor refactoring, and additional unit tests (including exceptions) f…
Feb 4, 2022
c1125ba
Clean up some phpstan issues
Feb 4, 2022
2dc6aa1
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 4, 2022
3ed98ab
Resolve phpstan issues
Feb 4, 2022
6bd181b
Eliminate spurious var_dump
Feb 4, 2022
0520466
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 9, 2022
3357af3
Minor refactoring of Cell calculation logic for array response
Feb 9, 2022
c05dd63
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 13, 2022
c7cbdf6
Reset phpstan baseline
Feb 13, 2022
719df3c
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 19, 2022
31cf8fb
Fix merge conflicts
Feb 19, 2022
8e8e8f4
Apply float precision for unit tests
Feb 19, 2022
76fbf38
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 22, 2022
568921c
Start work linking cells in spillage areas to the cell containing the…
Feb 23, 2022
c3652f3
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 23, 2022
7d5dc72
Maintain reference for cells inside a spillage range to prevent their…
Feb 23, 2022
b929dd1
Ensure that the `fromArray()` and `toArray()` functions retain the cu…
Feb 24, 2022
3806981
Allow recalc of all values for a spillage range
Feb 24, 2022
a67cffc
minor tweaks
Feb 24, 2022
200713a
Initial work on ODS reader to support array formulae
Feb 25, 2022
a83e3c6
Initial work on Gnumeric reader to support array formulae
Feb 26, 2022
dc718dd
Rename xlfn functions for Ods
Feb 26, 2022
45a770a
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 26, 2022
5672bd8
Resolve issues introduced during resolution of merge conflicts from m…
Feb 26, 2022
e30e7cb
More unit tests
Feb 26, 2022
7dfa06f
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 26, 2022
1574f48
Resolve `translateSeparator()` method to handle separators (row and c…
Feb 27, 2022
9413f00
Some Refactoring of the Ods Reader, moving all formula and address tr…
Feb 27, 2022
e1f278b
Unit tests for reading/writing array formulae from Ods
Feb 27, 2022
4d0f426
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Feb 27, 2022
cff8303
Re-merge from baseline
Feb 27, 2022
55be3b4
Minor typehint fixes
Feb 27, 2022
f64e2c2
Prep-work for handling matrix arithmetic in the calc engine, with som…
Feb 27, 2022
2c95f3a
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 4, 2022
c0f5a40
Suppress tests that we know will fail (for the moment)
Mar 4, 2022
fcc55a7
Fix for calculating array operations in the calculation engine (with …
Mar 4, 2022
e4b7d73
Unit tests for reading array formulae in Ods files
Mar 4, 2022
3dbc7dd
Handle aray formulae in the Gnumeric Reader (with unit tests)
Mar 4, 2022
b67841a
Additional Gnumeric Reader array formula unit tests
Mar 4, 2022
d6b6a11
Additional array formula tests for Ods Reader
Mar 5, 2022
85130dc
Precision in unit test float value
Mar 5, 2022
4a56261
Reverse `$asArray` and `$resetLog` arguments for calcuation methods; …
Mar 5, 2022
5346776
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 5, 2022
9c99f2f
Fix arguments for calculation call in `anchorarray()` pseudo-functin
Mar 5, 2022
ec6113e
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 6, 2022
6b0d724
Additional unit tests for array operations (in preparation for a swit…
Mar 7, 2022
96453e0
Fix to identify spillage cells from their arrayFormulaRange value
Mar 9, 2022
8ed2bab
Modifications to FORMULATEXT() to return correct values for cells in …
Mar 9, 2022
b1eb0e2
More unit tests for MMULT() function, to ensure correct calculation c…
Mar 9, 2022
5f79b74
Revert "Modifications to FORMULATEXT() to return correct values for c…
Mar 9, 2022
5ea78ae
Modifications to FORMULATEXT() to return correct values for cells in …
Mar 9, 2022
be57361
Additional unit tests for array/scalar operations
Mar 10, 2022
53aab72
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 10, 2022
96ac716
Fix sizing adjustments for reflective matrices (vectors increase to m…
Mar 10, 2022
3f69661
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 11, 2022
27fc7d5
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 13, 2022
ec3281b
Resolve phpstan
Mar 13, 2022
1ea119c
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 13, 2022
925c730
Some more unit tests for array functions and spillage; and updates to…
Mar 14, 2022
7ff8e8b
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 17, 2022
222b79b
Ensure that master can still merge in cleanly... knowing that if I do…
Mar 17, 2022
8f8257d
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 18, 2022
2acb3fe
Update branch and some additional unit tests
Mar 18, 2022
dc255fb
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 19, 2022
ca940c6
Re-baseline
Mar 19, 2022
2b3addc
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 19, 2022
fe1e0d2
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 24, 2022
6602dd6
More unit tests
Mar 24, 2022
adb0c13
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Mar 24, 2022
a3130ef
Flag functions as spillage functions. We may be able to use this to d…
Mar 25, 2022
3bb6b42
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Apr 12, 2022
1014a03
Resolve merge conflicts
Apr 12, 2022
c0c79c7
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Apr 13, 2022
e41c428
Initial creation of the version 2.0 Development branch
Apr 24, 2022
703604c
Remove Reader/Writer deprecations
Apr 25, 2022
0998e72
Eliminate underscore prefix in method names... no longer needed as an…
Apr 26, 2022
53a6ab9
Merge branch 'master' into 2.0-Development
Apr 27, 2022
02abb41
Merge branch 'master' into 2.0-Development
Apr 28, 2022
d613de1
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
Apr 30, 2022
f918847
Merge branch 'master' into 2.0-Development
May 7, 2022
acfd752
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
May 7, 2022
297817f
Merge branch 'master' into 2.0-Development
May 10, 2022
304e2b8
Merge branch 'master' into 2.0-Development
May 10, 2022
e51dabe
Merge branch 'master' into 2.0-Development
May 11, 2022
78ea02a
Update phpstan baseline
May 11, 2022
f5b4308
Merge branch 'master' into CalculationEngine-Array-Formulae-Initial-Work
May 11, 2022
e1e5888
PHP deprecation resolution
May 11, 2022
33d3442
Merge branch '2.0-Development' into CalculationEngine-Array-Formulae-…
May 13, 2022
feb7695
Merge resolutions
May 13, 2022
89b70a0
Merge branch 'master' into 2.0-Development
May 28, 2022
b1ca6ee
Merge branch '2.0-Development' into CalculationEngine-Array-Formulae-…
May 28, 2022
b1d1ce7
Re-baseline
May 28, 2022
05a1252
Merge branch 'master' into 2.0-Development
Jun 18, 2022
ba15a68
Merge from master, and rebase phpstan baseline
Jun 18, 2022
a8fc5bc
Merge branch '2.0-Development' into CalculationEngine-Array-Formulae-…
Jun 18, 2022
a40c708
Merge from 2.0 development, and rebase phpstan baseline
Jun 18, 2022
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
The table of contents is too big for display.
Diff view
Diff view
  •  
  •  
  •  
6 changes: 3 additions & 3 deletions docs/topics/accessing-cells.md
Original file line number Diff line number Diff line change
Expand Up @@ -131,10 +131,10 @@ Formats handled by the advanced value binder include:
- TRUE or FALSE (dependent on locale settings) are converted to booleans.
- Numeric strings identified as scientific (exponential) format are
converted to numbers.
- Fractions and vulgar fractions are converted to numbers, and
- Fractions and "vulgar" fractions are converted to numbers, and
an appropriate number format mask applied.
- Percentages are converted
to numbers, divided by 100, and an appropriate number format mask
- Percentages are converted to numbers, divided by 100, and an
appropriate number format mask
applied.
- Dates and times are converted to Excel timestamp values
(numbers), and an appropriate number format mask applied.
Expand Down
36 changes: 33 additions & 3 deletions docs/topics/calculation-engine.md
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,8 @@ formula calculation capabilities. A cell can be of a value type
which can be evaluated). For example, the formula `=SUM(A1:A10)`
evaluates to the sum of values in A1, A2, ..., A10.

Calling `getValue()` on a cell that contains a formula will return the formula itself.

To calculate a formula, you can call the cell containing the formula’s
method `getCalculatedValue()`, for example:

Expand All @@ -22,6 +24,30 @@ with PhpSpreadsheet, it evaluates to the value "64":

![09-command-line-calculation.png](./images/09-command-line-calculation.png)

Calling `getCalculatedValue()` on a cell that doesn't contain a formula will simply return the value of that cell; but if the cell does contain a formula, then PhpSpreadsheet will evaluate that formula to calculate the result.

There are a few useful mehods to help identify whether a cell contains a formula or a simple value; and if a formula, to provide further information about it:

```php
$spreadsheet->getActiveSheet()->getCell('E11')->isFormula();
```
will return a boolean true/false, telling you whether that cell contains a formula or not, so you can determine if a call to `getCalculatedVaue()` will need to perform an evaluation.

A formula can be either a simple formula, or an array formula; and another method will identify which it is:
```php
$spreadsheet->getActiveSheet()->getCell('E11')->isArrayFormula();
```
Finally, an array formula might result in a single cell result, or a result that can spill over into a range of cells; so for array formulae the following method also exists:
```php
$spreadsheet->getActiveSheet()->getCell('E11')->arrayFormulaRange();
```
which returns a string containing a cell reference (e.g. `E11`) or a cell range reference (e.g. `E11:G13`).


For more details on working with array formulae, see the [the recipes documentationn](./recipes.md/#array-formulae).

### Adjustments to formulae when Inserting/Deleting Columns/Rows

Another nice feature of PhpSpreadsheet's formula parser, is that it can
automatically adjust a formula when inserting/removing rows/columns.
Here's an example:
Expand Down Expand Up @@ -79,6 +105,11 @@ formula calculation is subject to PHP's language characteristics.
Not all functions are supported, for a comprehensive list, read the
[function list by name](../references/function-list-by-name.md).

#### Array arguments for Function Calls in Formulae

While most of the Excel function implementations now support array arguments, there are a few that should accept arrays as arguments but don't do so.
In these cases, the result may be a single value rather than an array; or it may be a `#VALUE!` error.

#### Operator precedence

In Excel `+` wins over `&`, just like `*` wins over `+` in ordinary
Expand All @@ -100,7 +131,7 @@ content.

- [Reference for this behaviour in PHP](https://php.net/manual/en/language.types.string.php#language.types.string.conversion)

#### Formulas don’t seem to be calculated in Excel2003 using compatibility pack?
#### Formulae don’t seem to be calculated in Excel2003 using compatibility pack?

This is normal behaviour of the compatibility pack, Xlsx displays this
correctly. Use `\PhpOffice\PhpSpreadsheet\Writer\Xls` if you really need
Expand Down Expand Up @@ -149,8 +180,7 @@ number of seconds from the PHP/Unix base date. The PHP/Unix base date
(0) is 00:00 UST on 1st January 1970. This value can be positive or
negative: so a value of -3600 would be 23:00 hrs on 31st December 1969;
while a value of +3600 would be 01:00 hrs on 1st January 1970. This
gives PHP a date range of between 14th December 1901 and 19th January
2038.
gives 32-bit PHP a date range of between 14th December 1901 and 19th January 2038.

#### PHP `DateTime` Objects

Expand Down
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
168 changes: 166 additions & 2 deletions docs/topics/recipes.md
Original file line number Diff line number Diff line change
Expand Up @@ -165,6 +165,168 @@ is further explained in [the calculation engine](./calculation-engine.md).
$value = $spreadsheet->getActiveSheet()->getCell('B8')->getCalculatedValue();
```

### Array Formulae

With version 2.0.0 of PhpSpreadsheet, we've introduced support for Excel "array formulae".

As a basic example, let's look at a receipt for buying some fruit:

![12-CalculationEngine-Basic-Formula.png](./images/12-CalculationEngine-Basic-Formula.png)

We can provide a "Cost" formula for each row of the receipt by multiplying the "Quantity" (column `B`) by the "Price" (column `C`); so for the "Apples" in row `2` we enter the formula `=$B2*$C2`. In PhpSpreadsheet, we would set this formula in cell `D2` using:
```php
$spreadsheet->getActiveSheet()->setCellValue('D2','=$B2*$C2');
```
and then do the equivalent for rows `3` to `6`.

To calculate the "Total", we would use a different formula, telling it to calculate the sum value of rows 2 to 6 in the "Cost" column:

![12-CalculationEngine-Basic-Formula-2.png](./images/12-CalculationEngine-Basic-Formula-2.png)

I'd imagine that most developers are familiar with this: we're setting a formula that uses an Excel function (the `SUM()` function) and specifying a range of cells to include in the sum (`$D$2:$D6`)
```php
$spreadsheet->getActiveSheet()->setCellValue('D7','=SUM($D$2:$D6');
```
However, we could have specified an alternative formula to calculate that result, using the arrays of the "Quantity" and "Cost" columns multiplied directly, and then summed together:

![12-CalculationEngine-Array-Formula.png](./images/12-CalculationEngine-Array-Formula.png)

Entering the formula `=SUM(B2:B6*C2:C6)` will calculate the same result; but because it's using arrays, we need to enter it as an "array formula". In MS Excel itself, we'd do this by using `Shift-Ctrl-Enter` rather than simply `Enter` when we define the formula in the formula edit box. MS Excel then shows that this is an array formula in the formula edit box by wrapping it in the `{}` braces (you don't enter these in the formula yourself; MS Excel does it).

If we want to create an array formula in PhpSpreadsheet, we also have to indicate that it is an array formula.
```php
$spreadsheet->getActiveSheet()->setCellValue('D7','=SUM(B2:B6*C2:C6)', true);
```
We do this by providing a third argument in the call to `setCellValue()` that is only appropriate when setting a cell value to a formula, and that is the boolean value `true` passed as the `$isArrayFormula` argument. If the value we're setting in the cell isn't a formula value, then this additional argument will be ignored.

Or to identify the biggest increase in like-for-like sales from one month to the next:

![12-CalculationEngine-Array-Formula-3.png](./images/12-CalculationEngine-Array-Formula-3.png)
```php
$spreadsheet->getActiveSheet()->setCellValue('F1','=MAX(B2:B6-C2:C6)', true);
```
Which tells us that the biggest increase in sales between December and January was 30 more (in this case, 30 more Lemons).

---

These are examples of array formula where the results are displayed in a single cell; but other array formulae might be displayed across several cells.
As an example, consider transposing a grid of data: MS Excel provides the `TRANSPOSE()` function for that purpose. Let's transpose our shopping list for the fruit:

![12-CalculationEngine-Array-Formula-2.png](./images/12-CalculationEngine-Array-Formula-2.png)

When we do this in MS Excel, we need to indicate ___all___ the cells that will contain the transposed data from cells `A1` to `D7`. We do this by selecting the cells where we want to display our transposed data either by holding the left mouse button down while we move with the mouse, or pressing `Shift` and using the arrow keys.
Once we've selected all the cells to hold our data, then we enter the formula `TRANSPOSE(A1:D7)` in the formula edit box, remembering to use `Shift-Ctrl-Enter` to tell MS Excel that this is an array formula.

We also need to specify that selected range if we create the same array formula in PhpSpreadsheet.
In addition to passing true for the `$isArrayFormula` argument, we also pass a fourth argument telling PhpSpreadsheet the range of cells that we want the transposed array to cover.
```php
$spreadsheet->getActiveSheet()->setCellValue('A10','=TRANSPOSE(A1:D7)', true, 'A10:G13');
```
Specifying this range tells PhpSpreadsheet (and MS Excel) that the result of the formula in cell `A10` is allowed to "spill" out into cells in that specified range; but also that it is limited to that range.
If you don't specify a range, then PhpSpreadsheet will only apply this formula to a single cell.

Note also that we still set this as the formula for the top-left cell of that range, cell `A10`.

If you want to use other methods like `setCellValueExplicit()`, `setCellValueByColumnAndRow()` or `setCellValueExplicitByColumnAndRow()`, then the same additional arguments are also available with these methods.
```php
$spreadsheet->getActiveSheet()
->setCellValueExplicit(
'A10',
'=TRANSPOSE(A1:D7)',
\PhpOffice\PhpSpreadsheet\Cell\DataType::TYPE_FORMULA,
true,
'A10:G13'
);
```

Simply setting an array formula in a cell and specifying the range won't populate the spillage area for that formula.
```php
$spreadsheet->getActiveSheet()
->setCellValue(
'A10',
'=SEQUENCE(3,3)',
true,
'A1:C3'
);

// Will return a null, because the formula for A1 hasn't been calculated to populate the spillage area
$result = $spreadsheet->getActiveSheet()->getCell('C3')->getValue();
```
To do that, we need to retrieve the calculated value for the cell.
```php
$spreadsheet->getActiveSheet()
->setCellValue(
'A10',
'=SEQUENCE(3,3)',
true,
'A1:C3'
);

$spreadsheet->getActiveSheet()->getCell('A1')->getCalculatedValue();

// Will return 9, because the formula for A1 has now been calculated, and the spillage area is populated
$result = $spreadsheet->getActiveSheet()->getCell('C3')->getValue();
```
When we call `getCalculatedValue()` for a cell that contains an array formula, PhpSpreadsheet returns the single value that would appear in that cell in MS Excel.
```php
// Will return integer 1, the value for that cell within the array
$a1result = $spreadsheet->getActiveSheet()->getCell('A1')->getCalculatedValue();
```

If we want to return the full array, then we need to call `getCalculatedValue()` with an additional argument, a boolean `true` to return the value as an array.
```php
// Will return an array [[1, 2, 3], [4, 5, 6], [7, 8, 9]]
$a1result = $spreadsheet->getActiveSheet()->getCell('A1')->getCalculatedValue(true);
```

---

Excel365 introduced a number of new functions that return arrays of results.
These include the `UNIQUE()`, `SORT()`, `SORTBY()`, `FILTER()`, `SEQUENCE()` and `RANDARRAY()` functions.
While not all of these have been implemented by the Calculation Engine in PhpSpreadsheet, so they cannot all be calculated within your PHP applications, they can still be read from and written to Xlsx files.

The way these functions are presented in MS Excel itself is slightly different to that of other array functions.

The `SEQUENCE()` function generates a series of values (in this case, starting with `-10` and increasing in steps of `2.5`); and here we're telling the formula to populate a 3x3 grid with these values.

![12-CalculationEngine-Spillage-Formula.png](./images/12-CalculationEngine-Spillage-Formula.png)

Note that this is visually different to the multi-cell array formulae like `TRANSPOSE()`. When we are positioned in the "spill" range for the grid, MS Excel highlights the area with a blue border; and the formula displayed in the formula editing field isn't wrapped in braces (`{}`).

And if we select any other cell inside the "spill" area other than the top-left cell, the formula in the formula edit field is greyed rather than displayed in black.

![12-CalculationEngine-Spillage-Formula-2.png](./images/12-CalculationEngine-Spillage-Formula-2.png)

When we enter this formula in MS Excel, we don't need to select the range of cells that it should occupy; nor do we need to enter it using `Ctrl-Shift-Enter`. MS Excel identifies that it is a multi-cell array formula because of the function that it uses, the `SEQUENCE()` function (and if there are nested function calls in the formula, then it must be the outermost functionin the tree).

However, PhpSpreadsheet isn't quite as intelligent (yet) and doesn't parse the formula to identify if it should be treated as an array formula or not; a formula is just a string of characters until it is actually evaluated. If we want to use this function through code, we still need to specify that it is an "array" function with the `$isArrayFormula` argument, and the range of cells that it should cover.

```php
$spreadsheet->getActiveSheet()->setCellValue('A1','=SEQUENCE(3,3,-10,2.5)', true, 'A1:C3');
```

### The Spill Operator

If you want to reference the entire spillage range of an array formula within another formula, you could do so using the standard Excel range operator (`:`, e.g. `A1:C3`); but you may not always know the range, especially for array functions that spill across as many cells as they need, like `UNIQUE()` and `FILTER()`.
To simplify this, MS Excel has introduced the "Spill" Operator (`#`).

![12-CalculationEngine-Spillage-Operator.png](./images/12-CalculationEngine-Spillage-Operator.png)

Using our `SEQUENCE()"`example, where the formula cell is `A1` and the result spills across the range `A1:C3`, we can use the Spill operator `A1#` to reference all the cells in that spillage range.
In this case, we're taking the absolute value of each cell in that range, and adding them together using the `SUM()` function to give us a result of 50.

PhpSpreadsheet doesn't currently support entry of a formula like this directly; but interally MS Excel implements the Spill Operator as a function (`ANCHORARRAY()`). MS Excel itself doesn't allow you to use this function in a formula, you have to use the "Spill" operator; but PhpSpreadsheet does allow you to use this internal Excel function.

To create this same function in PhpSpreadsheet, use:
```php
$spreadsheet->getActiveSheet()->setCellValue('D1','=SUM(ABS(ANCHORARRAY(A1)))', true);
```
Note that this does need to be flagged as an array function with the `$isArrayFormula` argument.

When the file is saved, and opened in MS Excel, it will be rendered correctly.



## Locale Settings for Formulae

Some localisation elements have been included in PhpSpreadsheet. You can
Expand All @@ -187,7 +349,7 @@ internal English coding.

```php
$formula = $spreadsheet->getActiveSheet()->getCell('B8')->getValue();
$translatedFormula = \PhpOffice\PhpSpreadsheet\Calculation\Calculation::getInstance()->_translateFormulaToLocale($formula);
$translatedFormula = \PhpOffice\PhpSpreadsheet\Calculation\Calculation::getInstance()->translateFormulaToLocale($formula);
```

You can also create a formula using the function names and argument
Expand All @@ -201,7 +363,7 @@ $spreadsheet->getActiveSheet()->setCellValue('B8',$internalFormula);
```

Currently, formula translation only translates the function names, the
constants TRUE and FALSE, and the function argument separators. Cell addressing using R1C1 formatting is not supported.
constants TRUE and FALSE (and NULL), Excel error messages, and the function argument separators. Cell addressing using R1C1 formatting is not supported.

At present, the following locale settings are supported:

Expand All @@ -224,6 +386,8 @@ Russian | русский язык | ru
Swedish | Svenska | sv
Turkish | Türkçe | tr

If anybody can provide translations for additional languages, particularly Basque (Euskara), Catalan (Català), Croatian (Hrvatski jezik), Galician (Galego), Greek (Ελληνικά), Slovak (Slovenčina) or Slovenian (Slovenščina); please feel free to volunteer your services, and we'll happily show you what is needed to contribute a new language.

## Write a newline character "\n" in a cell (ALT+"Enter")

In Microsoft Office Excel you get a line break in a cell by hitting
Expand Down
6 changes: 6 additions & 0 deletions infra/DocumentGenerator.php
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,9 @@ public static function generateFunctionListByCategory(array $phpSpreadsheetFunct
{
$result = "# Function list by category\n";
foreach (self::getCategories() as $categoryConstant => $category) {
if ($category === Category::CATEGORY_MICROSOFT_INTERNAL_PSEUDOFUNCTION) {
continue;
}
$result .= "\n";
$result .= "## {$categoryConstant}\n";
$result .= "\n";
Expand Down Expand Up @@ -78,6 +81,9 @@ public static function generateFunctionListByName(array $phpSpreadsheetFunctions
$result = "# Function list by name\n";
$lastAlphabet = null;
foreach ($phpSpreadsheetFunctions as $excelFunction => $functionInfo) {
if ($functionInfo['category'] === Category::CATEGORY_MICROSOFT_INTERNAL_PSEUDOFUNCTION) {
continue;
}
/** @var string $excelFunction */
$lengths = [25, 31, 37];
if ($lastAlphabet !== $excelFunction[0]) {
Expand Down
Loading