Skip to content

Commit

Permalink
Enable support for dates and percentages in Excel Database functions (#…
Browse files Browse the repository at this point in the history
…1875)

* Enable support for dates and percentages in Excel Database functions, and CountIf/AverageIf/etc
* Enable support for booleans in Excel Database functions
  • Loading branch information
Mark Baker committed Feb 22, 2021
1 parent 3764f30 commit 40a6dee
Show file tree
Hide file tree
Showing 7 changed files with 68 additions and 13 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Expand Up @@ -9,6 +9,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).

### 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)
- Alignment for ODS Writer [#1796](https://github.com/PHPOffice/PhpSpreadsheet/issues/1796)
- Basic implementation of the PERMUTATIONA() Statistical Function
Expand Down
7 changes: 3 additions & 4 deletions src/PhpSpreadsheet/Calculation/Database/DatabaseAbstract.php
Expand Up @@ -83,8 +83,6 @@ protected static function getFilteredColumn(array $database, $field, array $crit
}

/**
* @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)
*/
private static function buildQuery(array $criteriaNames, array $criteria): string
Expand Down Expand Up @@ -121,15 +119,16 @@ private static function executeQuery(array $database, string $query, $criteriaNa
$testConditionList = $query;
foreach ($criteriaNames as $key => $criteriaName) {
$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 = (is_string($dataValue)) ? Calculation::wrapResult(strtoupper($dataValue)) : $dataValue;
} else {
$dataValue = 'NULL';
}
$testConditionList = str_replace('[:' . $criteriaName . ']', $dataValue, $testConditionList);
}

// evaluate the criteria against the row data
$result = Calculation::getInstance()->_calculateFormulaValue('=' . $testConditionList);
// If the row failed to meet the criteria, remove it from the database
Expand Down
31 changes: 28 additions & 3 deletions src/PhpSpreadsheet/Calculation/Functions.php
Expand Up @@ -3,6 +3,7 @@
namespace PhpOffice\PhpSpreadsheet\Calculation;

use PhpOffice\PhpSpreadsheet\Cell\Cell;
use PhpOffice\PhpSpreadsheet\Shared\Date;

class Functions
{
Expand Down Expand Up @@ -252,9 +253,11 @@ public static function ifCondition($condition)
if ($condition === '') {
$condition = '=""';
}

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));
}

Expand All @@ -263,16 +266,38 @@ public static function ifCondition($condition)
preg_match('/(=|<[>=]?|>=?)(.*)/', $condition, $matches);
[, $operator, $operand] = $matches;

$operand = self::operandSpecialHandling($operand);
if (is_numeric(trim($operand, '"'))) {
$operand = trim($operand, '"');
} elseif (!is_numeric($operand)) {
} elseif (!is_numeric($operand) && $operand !== 'FALSE' && $operand !== 'TRUE') {
$operand = str_replace('"', '""', $operand);
$operand = Calculation::wrapResult(strtoupper($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.
*
Expand Down
Expand Up @@ -100,7 +100,7 @@ public function providerDCountA()
'Score',
[
['Subject', 'Score'],
['English', '>0.60'],
['English', '>60%'],
],
],
];
Expand Down
Expand Up @@ -59,6 +59,21 @@ protected function database2()
];
}

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()
{
return [
Expand Down Expand Up @@ -95,7 +110,25 @@ public function providerDCount()
null,
[
['Subject', 'Score'],
['English', '>0.63'],
['English', '>63%'],
],
],
[
3,
$this->database3(),
'Value',
[
['Status'],
[true],
],
],
[
5,
$this->database3(),
'Value',
[
['Status'],
['<>true'],
],
],
];
Expand Down
Expand Up @@ -73,8 +73,6 @@ public function providerDProduct()
['=Pear', null, null],
],
],
/*
* We don't yet support date handling in the search query
[
36,
$this->database2(),
Expand All @@ -93,7 +91,6 @@ public function providerDProduct()
['Test1', '<05-Jan-2017'],
],
],
*/
[
null,
$this->database1(),
Expand Down
Expand Up @@ -95,7 +95,7 @@ public function providerDSum()
],
],
/*
* We don't yet support woldcards in text search fields
* We don't yet support wildcards in text search fields
[
710000,
$this->database2(),
Expand Down

0 comments on commit 40a6dee

Please sign in to comment.