Merge pull request #2746 from PHPOffice/Issue-2730_Combined-Ranges

Support for "chained" range operators in the Calculation Engine
This commit is contained in:
Mark Baker 2022-04-13 18:16:14 +02:00 committed by GitHub
commit d4585ed0c6
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
4 changed files with 135 additions and 93 deletions

View File

@ -66,6 +66,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).
### Fixed ### Fixed
- Support for "chained" ranges (e.g. `A5:C10:C20:F1`) in the Calculation Engine; and also support for using named ranges with the Range operator (e.g. `NamedRange1:NamedRange2`) [Issue #2730](https://github.com/PHPOffice/PhpSpreadsheet/issues/2730) [PR #2746](https://github.com/PHPOffice/PhpSpreadsheet/pull/2746)
- Update Conditional Formatting ranges and rule conditions when inserting/deleting rows/columns [Issue #2678](https://github.com/PHPOffice/PhpSpreadsheet/issues/2678) [PR #2689](https://github.com/PHPOffice/PhpSpreadsheet/pull/2689) - Update Conditional Formatting ranges and rule conditions when inserting/deleting rows/columns [Issue #2678](https://github.com/PHPOffice/PhpSpreadsheet/issues/2678) [PR #2689](https://github.com/PHPOffice/PhpSpreadsheet/pull/2689)
- Allow `INDIRECT()` to accept row/column ranges as well as cell ranges [PR #2687](https://github.com/PHPOffice/PhpSpreadsheet/pull/2687) - Allow `INDIRECT()` to accept row/column ranges as well as cell ranges [PR #2687](https://github.com/PHPOffice/PhpSpreadsheet/pull/2687)
- Fix bug when deleting cells with hyperlinks, where the hyperlink was then being "inherited" by whatever cell moved to that cell address. - Fix bug when deleting cells with hyperlinks, where the hyperlink was then being "inherited" by whatever cell moved to that cell address.

View File

@ -127,7 +127,7 @@ parameters:
- -
message: "#^Offset 'value' does not exist on array\\|null\\.$#" message: "#^Offset 'value' does not exist on array\\|null\\.$#"
count: 3 count: 5
path: src/PhpSpreadsheet/Calculation/Calculation.php path: src/PhpSpreadsheet/Calculation/Calculation.php
- -

View File

@ -33,11 +33,11 @@ class Calculation
// Function (allow for the old @ symbol that could be used to prefix a function, but we'll ignore it) // Function (allow for the old @ symbol that could be used to prefix a function, but we'll ignore it)
const CALCULATION_REGEXP_FUNCTION = '@?(?:_xlfn\.)?([\p{L}][\p{L}\p{N}\.]*)[\s]*\('; const CALCULATION_REGEXP_FUNCTION = '@?(?:_xlfn\.)?([\p{L}][\p{L}\p{N}\.]*)[\s]*\(';
// Cell reference (cell or range of cells, with or without a sheet reference) // Cell reference (cell or range of cells, with or without a sheet reference)
const CALCULATION_REGEXP_CELLREF = '((([^\s,!&%^\/\*\+<>=-]*)|(\'.*?\')|(\".*?\"))!)?\$?\b([a-z]{1,3})\$?(\d{1,7})(?![\w.])'; const CALCULATION_REGEXP_CELLREF = '((([^\s,!&%^\/\*\+<>=:`-]*)|(\'.*?\')|(\".*?\"))!)?\$?\b([a-z]{1,3})\$?(\d{1,7})(?![\w.])';
// Cell reference (with or without a sheet reference) ensuring absolute/relative // Cell reference (with or without a sheet reference) ensuring absolute/relative
const CALCULATION_REGEXP_CELLREF_RELATIVE = '((([^\s\(,!&%^\/\*\+<>=-]*)|(\'.*?\')|(\".*?\"))!)?(\$?\b[a-z]{1,3})(\$?\d{1,7})(?![\w.])'; const CALCULATION_REGEXP_CELLREF_RELATIVE = '((([^\s\(,!&%^\/\*\+<>=:`-]*)|(\'.*?\')|(\".*?\"))!)?(\$?\b[a-z]{1,3})(\$?\d{1,7})(?![\w.])';
const CALCULATION_REGEXP_COLUMN_RANGE = '(((([^\s\(,!&%^\/\*\+<>=-]*)|(\'.*?\')|(\".*?\"))!)?(\$?[a-z]{1,3})):(?![.*])'; const CALCULATION_REGEXP_COLUMN_RANGE = '(((([^\s\(,!&%^\/\*\+<>=:`-]*)|(\'.*?\')|(\".*?\"))!)?(\$?[a-z]{1,3})):(?![.*])';
const CALCULATION_REGEXP_ROW_RANGE = '(((([^\s\(,!&%^\/\*\+<>=-]*)|(\'.*?\')|(\".*?\"))!)?(\$?[1-9][0-9]{0,6})):(?![.*])'; const CALCULATION_REGEXP_ROW_RANGE = '(((([^\s\(,!&%^\/\*\+<>=:`-]*)|(\'.*?\')|(\".*?\"))!)?(\$?[1-9][0-9]{0,6})):(?![.*])';
// Cell reference (with or without a sheet reference) ensuring absolute/relative // Cell reference (with or without a sheet reference) ensuring absolute/relative
// Cell ranges ensuring absolute/relative // Cell ranges ensuring absolute/relative
const CALCULATION_REGEXP_COLUMNRANGE_RELATIVE = '(\$?[a-z]{1,3}):(\$?[a-z]{1,3})'; const CALCULATION_REGEXP_COLUMNRANGE_RELATIVE = '(\$?[a-z]{1,3}):(\$?[a-z]{1,3})';
@ -4135,17 +4135,25 @@ class Calculation
$testPrevOp = $stack->last(1); $testPrevOp = $stack->last(1);
if ($testPrevOp !== null && $testPrevOp['value'] === ':') { if ($testPrevOp !== null && $testPrevOp['value'] === ':') {
// If we have a worksheet reference, then we're playing with a 3D reference // If we have a worksheet reference, then we're playing with a 3D reference
if ($matches[2] == '') { if ($matches[2] === '') {
// Otherwise, we 'inherit' the worksheet reference from the start cell reference // Otherwise, we 'inherit' the worksheet reference from the start cell reference
// The start of the cell range reference should be the last entry in $output // The start of the cell range reference should be the last entry in $output
$rangeStartCellRef = $output[count($output) - 1]['value']; $rangeStartCellRef = $output[count($output) - 1]['value'];
preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/i', $rangeStartCellRef, $rangeStartMatches); if ($rangeStartCellRef === ':') {
// Do we have chained range operators?
$rangeStartCellRef = $output[count($output) - 2]['value'];
}
preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/miu', $rangeStartCellRef, $rangeStartMatches);
if ($rangeStartMatches[2] > '') { if ($rangeStartMatches[2] > '') {
$val = $rangeStartMatches[2] . '!' . $val; $val = $rangeStartMatches[2] . '!' . $val;
} }
} else { } else {
$rangeStartCellRef = $output[count($output) - 1]['value']; $rangeStartCellRef = $output[count($output) - 1]['value'];
preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/i', $rangeStartCellRef, $rangeStartMatches); if ($rangeStartCellRef === ':') {
// Do we have chained range operators?
$rangeStartCellRef = $output[count($output) - 2]['value'];
}
preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/miu', $rangeStartCellRef, $rangeStartMatches);
if ($rangeStartMatches[2] !== $matches[2]) { if ($rangeStartMatches[2] !== $matches[2]) {
return $this->raiseFormulaError('3D Range references are not yet supported'); return $this->raiseFormulaError('3D Range references are not yet supported');
} }
@ -4159,7 +4167,7 @@ class Calculation
$outputItem = $stack->getStackItem('Cell Reference', $val, $val); $outputItem = $stack->getStackItem('Cell Reference', $val, $val);
$output[] = $outputItem; $output[] = $outputItem;
} else { // it's a variable, constant, string, number or boolean } else { // it's a variable, constant, string, number or boolean
$localeConstant = false; $localeConstant = false;
$stackItemType = 'Value'; $stackItemType = 'Value';
$stackItemReference = null; $stackItemReference = null;
@ -4168,39 +4176,62 @@ class Calculation
$testPrevOp = $stack->last(1); $testPrevOp = $stack->last(1);
if ($testPrevOp !== null && $testPrevOp['value'] === ':') { if ($testPrevOp !== null && $testPrevOp['value'] === ':') {
$stackItemType = 'Cell Reference'; $stackItemType = 'Cell Reference';
$startRowColRef = $output[count($output) - 1]['value']; if (
[$rangeWS1, $startRowColRef] = Worksheet::extractSheetTitle($startRowColRef, true); (preg_match('/^' . self::CALCULATION_REGEXP_DEFINEDNAME . '$/mui', $val) !== false) &&
$rangeSheetRef = $rangeWS1; ($this->spreadsheet->getNamedRange($val) !== null)
if ($rangeWS1 !== '') { ) {
$rangeWS1 .= '!'; $namedRange = $this->spreadsheet->getNamedRange($val);
} if ($namedRange !== null) {
$rangeSheetRef = trim($rangeSheetRef, "'"); $stackItemType = 'Defined Name';
[$rangeWS2, $val] = Worksheet::extractSheetTitle($val, true); $address = str_replace('$', '', $namedRange->getValue());
if ($rangeWS2 !== '') { $stackItemReference = $val;
$rangeWS2 .= '!'; if (strpos($address, ':') !== false) {
// We'll need to manipulate the stack for an actual named range rather than a named cell
$fromTo = explode(':', $address);
$to = array_pop($fromTo);
foreach ($fromTo as $from) {
$output[] = $stack->getStackItem($stackItemType, $from, $stackItemReference);
$output[] = $stack->getStackItem('Binary Operator', ':');
}
$address = $to;
}
$val = $address;
}
} else { } else {
$rangeWS2 = $rangeWS1; $startRowColRef = $output[count($output) - 1]['value'];
} [$rangeWS1, $startRowColRef] = Worksheet::extractSheetTitle($startRowColRef, true);
$rangeSheetRef = $rangeWS1;
if ($rangeWS1 !== '') {
$rangeWS1 .= '!';
}
$rangeSheetRef = trim($rangeSheetRef, "'");
[$rangeWS2, $val] = Worksheet::extractSheetTitle($val, true);
if ($rangeWS2 !== '') {
$rangeWS2 .= '!';
} else {
$rangeWS2 = $rangeWS1;
}
$refSheet = $pCellParent; $refSheet = $pCellParent;
if ($pCellParent !== null && $rangeSheetRef !== '' && $rangeSheetRef !== $pCellParent->getTitle()) { if ($pCellParent !== null && $rangeSheetRef !== '' && $rangeSheetRef !== $pCellParent->getTitle()) {
$refSheet = $pCellParent->getParent()->getSheetByName($rangeSheetRef); $refSheet = $pCellParent->getParent()->getSheetByName($rangeSheetRef);
} }
if (ctype_digit($val) && $val <= 1048576) { if (ctype_digit($val) && $val <= 1048576) {
// Row range // Row range
$stackItemType = 'Row Reference'; $stackItemType = 'Row Reference';
/** @var int $valx */ /** @var int $valx */
$valx = $val; $valx = $val;
$endRowColRef = ($refSheet !== null) ? $refSheet->getHighestDataColumn($valx) : 'XFD'; // Max 16,384 columns for Excel2007 $endRowColRef = ($refSheet !== null) ? $refSheet->getHighestDataColumn($valx) : 'XFD'; // Max 16,384 columns for Excel2007
$val = "{$rangeWS2}{$endRowColRef}{$val}"; $val = "{$rangeWS2}{$endRowColRef}{$val}";
} elseif (ctype_alpha($val) && strlen($val) <= 3) { } elseif (ctype_alpha($val) && strlen($val) <= 3) {
// Column range // Column range
$stackItemType = 'Column Reference'; $stackItemType = 'Column Reference';
$endRowColRef = ($refSheet !== null) ? $refSheet->getHighestDataRow($val) : 1048576; // Max 1,048,576 rows for Excel2007 $endRowColRef = ($refSheet !== null) ? $refSheet->getHighestDataRow($val) : 1048576; // Max 1,048,576 rows for Excel2007
$val = "{$rangeWS2}{$val}{$endRowColRef}"; $val = "{$rangeWS2}{$val}{$endRowColRef}";
}
$stackItemReference = $val;
} }
$stackItemReference = $val;
} elseif ($opCharacter == self::FORMULA_STRING_QUOTE) { } elseif ($opCharacter == self::FORMULA_STRING_QUOTE) {
// UnEscape any quotes within the string // UnEscape any quotes within the string
$val = self::wrapResult(str_replace('""', self::FORMULA_STRING_QUOTE, self::unwrapResult($val))); $val = self::wrapResult(str_replace('""', self::FORMULA_STRING_QUOTE, self::unwrapResult($val)));
@ -4461,21 +4492,29 @@ class Calculation
// Process the operation in the appropriate manner // Process the operation in the appropriate manner
switch ($token) { switch ($token) {
// Comparison (Boolean) Operators // Comparison (Boolean) Operators
case '>': // Greater than case '>': // Greater than
case '<': // Less than case '<': // Less than
case '>=': // Greater than or Equal to case '>=': // Greater than or Equal to
case '<=': // Less than or Equal to case '<=': // Less than or Equal to
case '=': // Equality case '=': // Equality
case '<>': // Inequality case '<>': // Inequality
$result = $this->executeBinaryComparisonOperation($operand1, $operand2, (string) $token, $stack); $result = $this->executeBinaryComparisonOperation($operand1, $operand2, (string) $token, $stack);
if (isset($storeKey)) { if (isset($storeKey)) {
$branchStore[$storeKey] = $result; $branchStore[$storeKey] = $result;
} }
break; break;
// Binary Operators // Binary Operators
case ':': // Range case ':': // Range
if ($operand1Data['type'] === 'Defined Name') {
if (preg_match('/$' . self::CALCULATION_REGEXP_DEFINEDNAME . '^/mui', $operand1Data['reference']) !== false) {
$definedName = $this->spreadsheet->getNamedRange($operand1Data['reference']);
if ($definedName !== null) {
$operand1Data['reference'] = $operand1Data['value'] = str_replace('$', '', $definedName->getValue());
}
}
}
if (strpos($operand1Data['reference'], '!') !== false) { if (strpos($operand1Data['reference'], '!') !== false) {
[$sheet1, $operand1Data['reference']] = Worksheet::extractSheetTitle($operand1Data['reference'], true); [$sheet1, $operand1Data['reference']] = Worksheet::extractSheetTitle($operand1Data['reference'], true);
} else { } else {

View File

@ -21,15 +21,7 @@ class RangeTest extends TestCase
{ {
$this->spreadSheet = new Spreadsheet(); $this->spreadSheet = new Spreadsheet();
$this->spreadSheet->getActiveSheet() $this->spreadSheet->getActiveSheet()
->setCellValue('A1', 1) ->fromArray(array_chunk(range(1, 240), 6), null, 'A1', true);
->setCellValue('B1', 2)
->setCellValue('C1', 3)
->setCellValue('A2', 4)
->setCellValue('B2', 5)
->setCellValue('C2', 6)
->setCellValue('A3', 7)
->setCellValue('B3', 8)
->setCellValue('C3', 9);
} }
/** /**
@ -40,33 +32,39 @@ class RangeTest extends TestCase
public function testRangeEvaluation(string $formula, $expectedResult): void public function testRangeEvaluation(string $formula, $expectedResult): void
{ {
$workSheet = $this->spreadSheet->getActiveSheet(); $workSheet = $this->spreadSheet->getActiveSheet();
$workSheet->setCellValue('E1', $formula); $workSheet->setCellValue('H1', $formula);
$actualRresult = $workSheet->getCell('E1')->getCalculatedValue(); $actualRresult = $workSheet->getCell('H1')->getCalculatedValue();
self::assertSame($expectedResult, $actualRresult); self::assertSame($expectedResult, $actualRresult);
} }
public function providerRangeEvaluation(): array public function providerRangeEvaluation(): array
{ {
return[ return[
['=SUM(A1:B3,A1:C2)', 48], 'Sum with Simple Range' => ['=SUM(A1:C3)', 72],
['=COUNT(A1:B3,A1:C2)', 12], 'Count with Simple Range' => ['=COUNT(A1:C3)', 9],
['=SUM(A1:B3 A1:C2)', 12], 'Sum with UNION #1' => ['=SUM(A1:B3,A1:C2)', 75],
['=COUNT(A1:B3 A1:C2)', 4], 'Count with UNION #1' => ['=COUNT(A1:B3,A1:C2)', 12],
['=SUM(A1:A3,C1:C3)', 30], 'Sum with INTERSECTION #1' => ['=SUM(A1:B3 A1:C2)', 18],
['=COUNT(A1:A3,C1:C3)', 6], 'Count with INTERSECTION #1' => ['=COUNT(A1:B3 A1:C2)', 4],
['=SUM(A1:A3 C1:C3)', Functions::null()], 'Sum with UNION #2' => ['=SUM(A1:A3,C1:C3)', 48],
['=COUNT(A1:A3 C1:C3)', 0], 'Count with UNION #2' => ['=COUNT(A1:A3,C1:C3)', 6],
['=SUM(A1:B2,B2:C3)', 40], 'Sum with INTERSECTION #2 - No Intersect' => ['=SUM(A1:A3 C1:C3)', Functions::null()],
['=COUNT(A1:B2,B2:C3)', 8], 'Count with INTERSECTION #2 - No Intersect' => ['=COUNT(A1:A3 C1:C3)', 0],
['=SUM(A1:B2 B2:C3)', 5], 'Sum with UNION #3' => ['=SUM(A1:B2,B2:C3)', 64],
['=COUNT(A1:B2 B2:C3)', 1], 'Count with UNION #3' => ['=COUNT(A1:B2,B2:C3)', 8],
['=SUM(A1:C1,A3:C3,B1:C3)', 63], 'Sum with INTERSECTION #3 - Single Cell' => ['=SUM(A1:B2 B2:C3)', 8],
['=COUNT(A1:C1,A3:C3,B1:C3)', 12], 'Count with INTERSECTION #3 - Single Cell' => ['=COUNT(A1:B2 B2:C3)', 1],
['=SUM(A1:C1,A3:C3 B1:C3)', 23], 'Sum with Triple UNION' => ['=SUM(A1:C1,A3:C3,B1:C3)', 99],
['=COUNT(A1:C1,A3:C3 B1:C3)', 5], 'Count with Triple UNION' => ['=COUNT(A1:C1,A3:C3,B1:C3)', 12],
['=SUM(Worksheet!A1:B3,Worksheet!A1:C2)', 48], 'Sum with UNION and INTERSECTION' => ['=SUM(A1:C1,A3:C3 B1:C3)', 35],
['=SUM(Worksheet!A1:Worksheet!B3,Worksheet!A1:Worksheet!C2)', 48], 'Count with UNION and INTERSECTION' => ['=COUNT(A1:C1,A3:C3 B1:C3)', 5],
'Sum with UNION with Worksheet Reference' => ['=SUM(Worksheet!A1:B3,Worksheet!A1:C2)', 75],
'Sum with UNION with full Worksheet Reference' => ['=SUM(Worksheet!A1:Worksheet!B3,Worksheet!A1:Worksheet!C2)', 75],
'Sum with Chained UNION #1' => ['=SUM(A3:B1:C2)', 72],
'Count with Chained UNION #1' => ['=COUNT(A3:B1:C2)', 9],
'Sum with Chained UNION #2' => ['=SUM(A5:C10:C20:F1)', 7260],
'Count with Chained UNION#2' => ['=COUNT(A5:C10:C20:F1)', 120],
]; ];
} }
@ -82,31 +80,35 @@ class RangeTest extends TestCase
/** /**
* @dataProvider providerNamedRangeEvaluation * @dataProvider providerNamedRangeEvaluation
*/ */
public function testNamedRangeEvaluation(string $group1, string $group2, string $formula, int $expectedResult): void public function testNamedRangeEvaluation(array $ranges, string $formula, int $expectedResult): void
{ {
$workSheet = $this->spreadSheet->getActiveSheet(); $workSheet = $this->spreadSheet->getActiveSheet();
$this->spreadSheet->addNamedRange(new NamedRange('GROUP1', $workSheet, $group1)); foreach ($ranges as $id => $range) {
$this->spreadSheet->addNamedRange(new NamedRange('GROUP2', $workSheet, $group2)); $this->spreadSheet->addNamedRange(new NamedRange('GROUP' . ++$id, $workSheet, $range));
}
$workSheet->setCellValue('E1', $formula); $workSheet->setCellValue('H1', $formula);
$sumRresult = $workSheet->getCell('E1')->getCalculatedValue(); $sumRresult = $workSheet->getCell('H1')->getCalculatedValue();
self::assertSame($expectedResult, $sumRresult); self::assertSame($expectedResult, $sumRresult);
} }
public function providerNamedRangeEvaluation(): array public function providerNamedRangeEvaluation(): array
{ {
return[ return[
['$A$1:$B$3', '$A$1:$C$2', '=SUM(GROUP1,GROUP2)', 48], [['$A$1:$B$3', '$A$1:$C$2'], '=SUM(GROUP1,GROUP2)', 75],
['$A$1:$B$3', '$A$1:$C$2', '=COUNT(GROUP1,GROUP2)', 12], [['$A$1:$B$3', '$A$1:$C$2'], '=COUNT(GROUP1,GROUP2)', 12],
['$A$1:$B$3', '$A$1:$C$2', '=SUM(GROUP1 GROUP2)', 12], [['$A$1:$B$3', '$A$1:$C$2'], '=SUM(GROUP1 GROUP2)', 18],
['$A$1:$B$3', '$A$1:$C$2', '=COUNT(GROUP1 GROUP2)', 4], [['$A$1:$B$3', '$A$1:$C$2'], '=COUNT(GROUP1 GROUP2)', 4],
['$A$1:$B$2', '$B$2:$C$3', '=SUM(GROUP1,GROUP2)', 40], [['$A$1:$B$2', '$B$2:$C$3'], '=SUM(GROUP1,GROUP2)', 64],
['$A$1:$B$2', '$B$2:$C$3', '=COUNT(GROUP1,GROUP2)', 8], [['$A$1:$B$2', '$B$2:$C$3'], '=COUNT(GROUP1,GROUP2)', 8],
['$A$1:$B$2', '$B$2:$C$3', '=SUM(GROUP1 GROUP2)', 5], [['$A$1:$B$2', '$B$2:$C$3'], '=SUM(GROUP1 GROUP2)', 8],
['$A$1:$B$2', '$B$2:$C$3', '=COUNT(GROUP1 GROUP2)', 1], [['$A$1:$B$2', '$B$2:$C$3'], '=COUNT(GROUP1 GROUP2)', 1],
['Worksheet!$A$1:$B$2', 'Worksheet!$B$2:$C$3', '=SUM(GROUP1,GROUP2)', 40], [['$A$5', '$C$10:$C$20', '$F$1'], '=SUM(GROUP1:GROUP2:GROUP3)', 7260],
['Worksheet!$A$1:Worksheet!$B$2', 'Worksheet!$B$2:Worksheet!$C$3', '=SUM(GROUP1,GROUP2)', 40], [['$A$5:$A$7', '$C$20', '$F$1'], '=SUM(GROUP1:GROUP2:GROUP3)', 7260],
[['$A$5:$A$7', '$C$10:$C$20', '$F$1'], '=SUM(GROUP1:GROUP2:GROUP3)', 7260],
[['Worksheet!$A$1:$B$2', 'Worksheet!$B$2:$C$3'], '=SUM(GROUP1,GROUP2)', 64],
[['Worksheet!$A$1:Worksheet!$B$2', 'Worksheet!$B$2:Worksheet!$C$3'], '=SUM(GROUP1,GROUP2)', 64],
]; ];
} }
@ -132,9 +134,9 @@ class RangeTest extends TestCase
public function providerUTF8NamedRangeEvaluation(): array public function providerUTF8NamedRangeEvaluation(): array
{ {
return[ return[
[['Γειά', 'σου', 'Κόσμε'], ['$A$1', '$B$1:$B$2', '$C$1:$C$3'], '=SUM(Γειά,σου,Κόσμε)', 26], [['Γειά', 'σου', 'Κόσμε'], ['$A$1', '$B$1:$B$2', '$C$1:$C$3'], '=SUM(Γειά,σου,Κόσμε)', 38],
[['Γειά', 'σου', 'Κόσμε'], ['$A$1', '$B$1:$B$2', '$C$1:$C$3'], '=COUNT(Γειά,σου,Κόσμε)', 6], [['Γειά', 'σου', 'Κόσμε'], ['$A$1', '$B$1:$B$2', '$C$1:$C$3'], '=COUNT(Γειά,σου,Κόσμε)', 6],
[['Здравствуй', 'мир'], ['$A$1:$A$3', '$C$1:$C$3'], '=SUM(Здравствуй,мир)', 30], [['Здравствуй', 'мир'], ['$A$1:$A$3', '$C$1:$C$3'], '=SUM(Здравствуй,мир)', 48],
]; ];
} }