Enable support for dates and percentages in Excel Database functions (#1875)

* Enable support for dates and percentages in Excel Database functions, and CountIf/AverageIf/etc
* Enable support for booleans in Excel Database functions
This commit is contained in:
Mark Baker 2021-02-22 20:40:40 +01:00 committed by GitHub
parent 3764f30354
commit 40a6dee0a4
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
7 changed files with 68 additions and 13 deletions

View File

@ -9,6 +9,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).
### Added ### Added
- Support for date values and percentages in query parameters for Database functions, and the IF expressions in functions like COUNTIF() and AVERAGEIF(). [#1875](https://github.com/PHPOffice/PhpSpreadsheet/pull/1875)
- Implemented DataBar for conditional formatting in Xlsx, providing read/write and creation of (type, value, direction, fills, border, axis position, color settings) as DataBar options in Excel. [#1754](https://github.com/PHPOffice/PhpSpreadsheet/pull/1754) - Implemented DataBar for conditional formatting in Xlsx, providing read/write and creation of (type, value, direction, fills, border, axis position, color settings) as DataBar options in Excel. [#1754](https://github.com/PHPOffice/PhpSpreadsheet/pull/1754)
- Alignment for ODS Writer [#1796](https://github.com/PHPOffice/PhpSpreadsheet/issues/1796) - Alignment for ODS Writer [#1796](https://github.com/PHPOffice/PhpSpreadsheet/issues/1796)
- Basic implementation of the PERMUTATIONA() Statistical Function - Basic implementation of the PERMUTATIONA() Statistical Function

View File

@ -83,8 +83,6 @@ abstract class DatabaseAbstract
} }
/** /**
* @TODO Support for Dates (including handling for >, <=, etc)
* @TODO Suport for formatted numerics (e.g. '>12.5%' => '>0.125')
* @TODO Suport for wildcard ? and * in strings (includng escaping) * @TODO Suport for wildcard ? and * in strings (includng escaping)
*/ */
private static function buildQuery(array $criteriaNames, array $criteria): string private static function buildQuery(array $criteriaNames, array $criteria): string
@ -121,7 +119,9 @@ abstract class DatabaseAbstract
$testConditionList = $query; $testConditionList = $query;
foreach ($criteriaNames as $key => $criteriaName) { foreach ($criteriaNames as $key => $criteriaName) {
$key = array_search($criteriaName, $fieldNames, true); $key = array_search($criteriaName, $fieldNames, true);
if (isset($dataValues[$key])) { if (is_bool($dataValues[$key])) {
$dataValue = ($dataValues[$key]) ? 'TRUE' : 'FALSE';
} elseif ($dataValues[$key] !== null) {
$dataValue = $dataValues[$key]; $dataValue = $dataValues[$key];
$dataValue = (is_string($dataValue)) ? Calculation::wrapResult(strtoupper($dataValue)) : $dataValue; $dataValue = (is_string($dataValue)) ? Calculation::wrapResult(strtoupper($dataValue)) : $dataValue;
} else { } else {
@ -129,7 +129,6 @@ abstract class DatabaseAbstract
} }
$testConditionList = str_replace('[:' . $criteriaName . ']', $dataValue, $testConditionList); $testConditionList = str_replace('[:' . $criteriaName . ']', $dataValue, $testConditionList);
} }
// evaluate the criteria against the row data // evaluate the criteria against the row data
$result = Calculation::getInstance()->_calculateFormulaValue('=' . $testConditionList); $result = Calculation::getInstance()->_calculateFormulaValue('=' . $testConditionList);
// If the row failed to meet the criteria, remove it from the database // If the row failed to meet the criteria, remove it from the database

View File

@ -3,6 +3,7 @@
namespace PhpOffice\PhpSpreadsheet\Calculation; namespace PhpOffice\PhpSpreadsheet\Calculation;
use PhpOffice\PhpSpreadsheet\Cell\Cell; use PhpOffice\PhpSpreadsheet\Cell\Cell;
use PhpOffice\PhpSpreadsheet\Shared\Date;
class Functions class Functions
{ {
@ -252,9 +253,11 @@ class Functions
if ($condition === '') { if ($condition === '') {
$condition = '=""'; $condition = '=""';
} }
if (!is_string($condition) || !in_array($condition[0], ['>', '<', '='])) { if (!is_string($condition) || !in_array($condition[0], ['>', '<', '='])) {
if (!is_numeric($condition)) { $condition = self::operandSpecialHandling($condition);
if (is_bool($condition)) {
return '=' . ($condition ? 'TRUE' : 'FALSE');
} elseif (!is_numeric($condition)) {
$condition = Calculation::wrapResult(strtoupper($condition)); $condition = Calculation::wrapResult(strtoupper($condition));
} }
@ -263,9 +266,10 @@ class Functions
preg_match('/(=|<[>=]?|>=?)(.*)/', $condition, $matches); preg_match('/(=|<[>=]?|>=?)(.*)/', $condition, $matches);
[, $operator, $operand] = $matches; [, $operator, $operand] = $matches;
$operand = self::operandSpecialHandling($operand);
if (is_numeric(trim($operand, '"'))) { if (is_numeric(trim($operand, '"'))) {
$operand = trim($operand, '"'); $operand = trim($operand, '"');
} elseif (!is_numeric($operand)) { } elseif (!is_numeric($operand) && $operand !== 'FALSE' && $operand !== 'TRUE') {
$operand = str_replace('"', '""', $operand); $operand = str_replace('"', '""', $operand);
$operand = Calculation::wrapResult(strtoupper($operand)); $operand = Calculation::wrapResult(strtoupper($operand));
} }
@ -273,6 +277,27 @@ class Functions
return str_replace('""""', '""', $operator . $operand); return str_replace('""""', '""', $operator . $operand);
} }
private static function operandSpecialHandling($operand)
{
if (is_numeric($operand) || is_bool($operand)) {
return $operand;
} elseif (strtoupper($operand) === Calculation::getTRUE() || strtoupper($operand) === Calculation::getFALSE()) {
return strtoupper($operand);
}
// Check for percentage
if (preg_match('/^\-?\d*\.?\d*\s?\%$/', $operand)) {
return ((float) rtrim($operand, '%')) / 100;
}
// Check for dates
if (($dateValueOperand = Date::stringToExcel($operand)) !== false) {
return $dateValueOperand;
}
return $operand;
}
/** /**
* ERROR_TYPE. * ERROR_TYPE.
* *

View File

@ -100,7 +100,7 @@ class DCountATest extends TestCase
'Score', 'Score',
[ [
['Subject', 'Score'], ['Subject', 'Score'],
['English', '>0.60'], ['English', '>60%'],
], ],
], ],
]; ];

View File

@ -59,6 +59,21 @@ class DCountTest extends TestCase
]; ];
} }
protected function database3()
{
return [
['Status', 'Value'],
[false, 1],
[true, 2],
[true, 4],
[false, 8],
[true, 16],
[false, 32],
[false, 64],
[false, 128],
];
}
public function providerDCount() public function providerDCount()
{ {
return [ return [
@ -95,7 +110,25 @@ class DCountTest extends TestCase
null, null,
[ [
['Subject', 'Score'], ['Subject', 'Score'],
['English', '>0.63'], ['English', '>63%'],
],
],
[
3,
$this->database3(),
'Value',
[
['Status'],
[true],
],
],
[
5,
$this->database3(),
'Value',
[
['Status'],
['<>true'],
], ],
], ],
]; ];

View File

@ -73,8 +73,6 @@ class DProductTest extends TestCase
['=Pear', null, null], ['=Pear', null, null],
], ],
], ],
/*
* We don't yet support date handling in the search query
[ [
36, 36,
$this->database2(), $this->database2(),
@ -93,7 +91,6 @@ class DProductTest extends TestCase
['Test1', '<05-Jan-2017'], ['Test1', '<05-Jan-2017'],
], ],
], ],
*/
[ [
null, null,
$this->database1(), $this->database1(),

View File

@ -95,7 +95,7 @@ class DSumTest extends TestCase
], ],
], ],
/* /*
* We don't yet support woldcards in text search fields * We don't yet support wildcards in text search fields
[ [
710000, 710000,
$this->database2(), $this->database2(),