Merge pull request #2899 from PHPOffice/Issue-2874_Calculation-Engine-Quoted-Worksheet-Regexp
Issue 2874 calculation engine quoted worksheet regexp
This commit is contained in:
commit
1f85f15cd9
|
|
@ -33,17 +33,17 @@ class Calculation
|
|||
// 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]*\(';
|
||||
// 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
|
||||
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_ROW_RANGE = '(((([^\s\(,!&%^\/\*\+<>=:`-]*)|(\'.*?\')|(\".*?\"))!)?(\$?[1-9][0-9]{0,6})):(?![.*])';
|
||||
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_ROW_RANGE = '(((([^\s\(,!&%^\/\*\+<>=:`-]*)|(\'(?:[^\']|\'[^!])+?\')|(\"(?:[^\"]|\"[^!])+?\"))!)?(\$?[1-9][0-9]{0,6})):(?![.*])';
|
||||
// Cell reference (with or without a sheet reference) ensuring absolute/relative
|
||||
// Cell ranges ensuring absolute/relative
|
||||
const CALCULATION_REGEXP_COLUMNRANGE_RELATIVE = '(\$?[a-z]{1,3}):(\$?[a-z]{1,3})';
|
||||
const CALCULATION_REGEXP_ROWRANGE_RELATIVE = '(\$?\d{1,7}):(\$?\d{1,7})';
|
||||
// Defined Names: Named Range of cells, or Named Formulae
|
||||
const CALCULATION_REGEXP_DEFINEDNAME = '((([^\s,!&%^\/\*\+<>=-]*)|(\'.*?\')|(\".*?\"))!)?([_\p{L}][_\p{L}\p{N}\.]*)';
|
||||
const CALCULATION_REGEXP_DEFINEDNAME = '((([^\s,!&%^\/\*\+<>=-]*)|(\'(?:[^\']|\'[^!])+?\')|(\"(?:[^\"]|\"[^!])+?\"))!)?([_\p{L}][_\p{L}\p{N}\.]*)';
|
||||
// Error
|
||||
const CALCULATION_REGEXP_ERROR = '\#[A-Z][A-Z0_\/]*[!\?]?';
|
||||
|
||||
|
|
@ -4203,7 +4203,7 @@ class Calculation
|
|||
$expectingOperator = false;
|
||||
}
|
||||
$stack->push('Brace', '(');
|
||||
} elseif (preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/i', $val, $matches)) {
|
||||
} elseif (preg_match('/^' . self::CALCULATION_REGEXP_CELLREF . '$/miu', $val, $matches)) {
|
||||
// Watch for this case-change when modifying to allow cell references in different worksheets...
|
||||
// Should only be applied to the actual cell column, not the worksheet name
|
||||
// If the last entry on the stack was a : operator, then we have a cell range reference
|
||||
|
|
@ -4326,6 +4326,8 @@ class Calculation
|
|||
$val = $rowRangeReference[1];
|
||||
$length = strlen($rowRangeReference[1]);
|
||||
$stackItemType = 'Row Reference';
|
||||
// unescape any apostrophes or double quotes in worksheet name
|
||||
$val = str_replace(["''", '""'], ["'", '"'], $val);
|
||||
$column = 'A';
|
||||
if (($testPrevOp !== null && $testPrevOp['value'] === ':') && $pCellParent !== null) {
|
||||
$column = $pCellParent->getHighestDataColumn($val);
|
||||
|
|
@ -4338,6 +4340,8 @@ class Calculation
|
|||
$val = $columnRangeReference[1];
|
||||
$length = strlen($val);
|
||||
$stackItemType = 'Column Reference';
|
||||
// unescape any apostrophes or double quotes in worksheet name
|
||||
$val = str_replace(["''", '""'], ["'", '"'], $val);
|
||||
$row = '1';
|
||||
if (($testPrevOp !== null && $testPrevOp['value'] === ':') && $pCellParent !== null) {
|
||||
$row = $pCellParent->getHighestDataRow($val);
|
||||
|
|
|
|||
|
|
@ -162,6 +162,78 @@ class ParseFormulaTest extends TestCase
|
|||
],
|
||||
'=B:C',
|
||||
],
|
||||
'Combined Cell Reference and Column Range' => [
|
||||
[
|
||||
['type' => 'Column Reference', 'value' => "'sheet1'!A1", 'reference' => "'sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'sheet1'!A1048576", 'reference' => "'sheet1'!A1048576"],
|
||||
['type' => 'Binary Operator', 'value' => ':', 'reference' => null],
|
||||
['type' => 'Operand Count for Function MIN()', 'value' => 1, 'reference' => null],
|
||||
['type' => 'Function', 'value' => 'MIN(', 'reference' => null],
|
||||
['type' => 'Cell Reference', 'value' => "'sheet1'!A1", 'reference' => "'sheet1'!A1"],
|
||||
['type' => 'Binary Operator', 'value' => '+', 'reference' => null],
|
||||
],
|
||||
"=MIN('sheet1'!A:A) + 'sheet1'!A1",
|
||||
],
|
||||
'Combined Cell Reference and Column Range with quote' => [
|
||||
[
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1048576", 'reference' => "'Mark's sheet1'!A1048576"],
|
||||
['type' => 'Binary Operator', 'value' => ':', 'reference' => null],
|
||||
['type' => 'Operand Count for Function MIN()', 'value' => 1, 'reference' => null],
|
||||
['type' => 'Function', 'value' => 'MIN(', 'reference' => null],
|
||||
['type' => 'Cell Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Binary Operator', 'value' => '+', 'reference' => null],
|
||||
],
|
||||
"=MIN('Mark''s sheet1'!A:A) + 'Mark''s sheet1'!A1",
|
||||
],
|
||||
'Combined Cell Reference and Column Range with unescaped quote' => [
|
||||
[
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1048576", 'reference' => "'Mark's sheet1'!A1048576"],
|
||||
['type' => 'Binary Operator', 'value' => ':', 'reference' => null],
|
||||
['type' => 'Operand Count for Function MIN()', 'value' => 1, 'reference' => null],
|
||||
['type' => 'Function', 'value' => 'MIN(', 'reference' => null],
|
||||
['type' => 'Cell Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Binary Operator', 'value' => '+', 'reference' => null],
|
||||
],
|
||||
"=MIN('Mark's sheet1'!A:A) + 'Mark's sheet1'!A1",
|
||||
],
|
||||
'Combined Column Range and Cell Reference' => [
|
||||
[
|
||||
['type' => 'Cell Reference', 'value' => "'sheet1'!A1", 'reference' => "'sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'sheet1'!A1", 'reference' => "'sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'sheet1'!A1048576", 'reference' => "'sheet1'!A1048576"],
|
||||
['type' => 'Binary Operator', 'value' => ':', 'reference' => null],
|
||||
['type' => 'Operand Count for Function MIN()', 'value' => 1, 'reference' => null],
|
||||
['type' => 'Function', 'value' => 'MIN(', 'reference' => null],
|
||||
['type' => 'Binary Operator', 'value' => '+', 'reference' => null],
|
||||
],
|
||||
"='sheet1'!A1 + MIN('sheet1'!A:A)",
|
||||
],
|
||||
'Combined Column Range and Cell Reference with quote' => [
|
||||
[
|
||||
['type' => 'Cell Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1048576", 'reference' => "'Mark's sheet1'!A1048576"],
|
||||
['type' => 'Binary Operator', 'value' => ':', 'reference' => null],
|
||||
['type' => 'Operand Count for Function MIN()', 'value' => 1, 'reference' => null],
|
||||
['type' => 'Function', 'value' => 'MIN(', 'reference' => null],
|
||||
['type' => 'Binary Operator', 'value' => '+', 'reference' => null],
|
||||
],
|
||||
"='Mark''s sheet1'!A1 + MIN('Mark''s sheet1'!A:A)",
|
||||
],
|
||||
'Combined Column Range and Cell Reference with unescaped quote' => [
|
||||
[
|
||||
['type' => 'Cell Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1", 'reference' => "'Mark's sheet1'!A1"],
|
||||
['type' => 'Column Reference', 'value' => "'Mark's sheet1'!A1048576", 'reference' => "'Mark's sheet1'!A1048576"],
|
||||
['type' => 'Binary Operator', 'value' => ':', 'reference' => null],
|
||||
['type' => 'Operand Count for Function MIN()', 'value' => 1, 'reference' => null],
|
||||
['type' => 'Function', 'value' => 'MIN(', 'reference' => null],
|
||||
['type' => 'Binary Operator', 'value' => '+', 'reference' => null],
|
||||
],
|
||||
"='Mark's sheet1'!A1 + MIN('Mark's sheet1'!A:A)",
|
||||
],
|
||||
'Range with Defined Names' => [
|
||||
[
|
||||
['type' => 'Defined Name', 'value' => 'GROUP1', 'reference' => 'GROUP1'],
|
||||
|
|
|
|||
Loading…
Reference in New Issue