Calculation/Statistical :: Add MAXIFS, MINIFS, COUNTIFS and Remove MINIF, MAXIF (#1059)
* #1056 - replace invalid minif/maxif functions by not implemented minifs/maxifs minif/maxif is not support in Excel, Google Spreadsheets, Libreoffice https://support.office.com/en-us/article/excel-functions-alphabetical-b3944572-255d-4efb-bb96-c6d90033e188#bm13 * #1056 - implement minifs/maxifs Copy-pasted sumifs... https://github.com/PHPOffice/PhpSpreadsheet/blob/1.8.1/src/PhpSpreadsheet/Calculation/MathTrig.php#L1254 * #1056 - implement countifs * #1056 - fix code style composer check composer fix * #1056 - update changelog
This commit is contained in:
parent
22190615ce
commit
42fc71f314
|
@ -10,6 +10,7 @@ and this project adheres to [Semantic Versioning](https://semver.org).
|
|||
### Added
|
||||
|
||||
- When <br> appears in a table cell, set the cell to wrap [Issue #1071](https://github.com/PHPOffice/PhpSpreadsheet/issues/1071) and [PR #1070](https://github.com/PHPOffice/PhpSpreadsheet/pull/1070)
|
||||
- Add MAXIFS, MINIFS, COUNTIFS and Remove MINIF, MAXIF - [Issue #1056](https://github.com/PHPOffice/PhpSpreadsheet/issues/1056)
|
||||
|
||||
### Fixed
|
||||
|
||||
|
|
|
@ -333,7 +333,7 @@ COUNT | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNT
|
|||
COUNTA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTA
|
||||
COUNTBLANK | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTBLANK
|
||||
COUNTIF | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTIF
|
||||
COUNTIFS | **Not yet Implemented**
|
||||
COUNTIFS | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTIFS
|
||||
COVAR | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COVAR
|
||||
CRITBINOM | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::CRITBINOM
|
||||
DEVSQ | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::DEVSQ
|
||||
|
@ -361,12 +361,12 @@ LOGINV | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::LOGINV
|
|||
LOGNORMDIST | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::LOGNORMDIST
|
||||
MAX | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAX
|
||||
MAXA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAXA
|
||||
MAXIF | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAXIF
|
||||
MAXIFS | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAXIFS
|
||||
MEDIAN | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MEDIAN
|
||||
MEDIANIF | **Not yet Implemented**
|
||||
MIN | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MIN
|
||||
MINA | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINA
|
||||
MINIF | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINIF
|
||||
MINIFS | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINIFS
|
||||
MODE | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MODE
|
||||
MODE.SNGL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MODE
|
||||
NEGBINOMDIST | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::NEGBINOMDIST
|
||||
|
|
|
@ -79,7 +79,7 @@ COUNT | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet
|
|||
COUNTA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTA
|
||||
COUNTBLANK | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTBLANK
|
||||
COUNTIF | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTIF
|
||||
COUNTIFS | CATEGORY_STATISTICAL | **Not yet Implemented**
|
||||
COUNTIFS | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::COUNTIFS
|
||||
COUPDAYBS | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::COUPDAYBS
|
||||
COUPDAYS | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::COUPDAYS
|
||||
COUPDAYSNC | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::COUPDAYSNC
|
||||
|
@ -295,7 +295,7 @@ Excel Function | Category | PhpSpreadsheet Function
|
|||
MATCH | CATEGORY_LOOKUP_AND_REFERENCE | \PhpOffice\PhpSpreadsheet\Calculation\LookupRef::MATCH
|
||||
MAX | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAX
|
||||
MAXA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAXA
|
||||
MAXIF | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MAXIF
|
||||
MAXIFS | CATEGORY_STATISTICAL | **Not yet Implemented**
|
||||
MDETERM | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::MDETERM
|
||||
MDURATION | CATEGORY_FINANCIAL | **Not yet Implemented**
|
||||
MEDIAN | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MEDIAN
|
||||
|
@ -304,7 +304,7 @@ MID | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet
|
|||
MIDB | CATEGORY_TEXT_AND_DATA | \PhpOffice\PhpSpreadsheet\Calculation\TextData::MID
|
||||
MIN | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MIN
|
||||
MINA | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINA
|
||||
MINIF | CATEGORY_STATISTICAL | \PhpOffice\PhpSpreadsheet\Calculation\Statistical::MINIF
|
||||
MINIFS | CATEGORY_STATISTICAL | **Not yet Implemented**
|
||||
MINUTE | CATEGORY_DATE_AND_TIME | \PhpOffice\PhpSpreadsheet\Calculation\DateTime::MINUTE
|
||||
MINVERSE | CATEGORY_MATH_AND_TRIG | \PhpOffice\PhpSpreadsheet\Calculation\MathTrig::MINVERSE
|
||||
MIRR | CATEGORY_FINANCIAL | \PhpOffice\PhpSpreadsheet\Calculation\Financial::MIRR
|
||||
|
|
|
@ -527,7 +527,7 @@ class Calculation
|
|||
],
|
||||
'COUNTIFS' => [
|
||||
'category' => Category::CATEGORY_STATISTICAL,
|
||||
'functionCall' => [Functions::class, 'DUMMY'],
|
||||
'functionCall' => [Statistical::class, 'COUNTIFS'],
|
||||
'argumentCount' => '2+',
|
||||
],
|
||||
'COUPDAYBS' => [
|
||||
|
@ -1356,10 +1356,10 @@ class Calculation
|
|||
'functionCall' => [Statistical::class, 'MAXA'],
|
||||
'argumentCount' => '1+',
|
||||
],
|
||||
'MAXIF' => [
|
||||
'MAXIFS' => [
|
||||
'category' => Category::CATEGORY_STATISTICAL,
|
||||
'functionCall' => [Statistical::class, 'MAXIF'],
|
||||
'argumentCount' => '2+',
|
||||
'functionCall' => [Statistical::class, 'MAXIFS'],
|
||||
'argumentCount' => '3+',
|
||||
],
|
||||
'MDETERM' => [
|
||||
'category' => Category::CATEGORY_MATH_AND_TRIG,
|
||||
|
@ -1401,10 +1401,10 @@ class Calculation
|
|||
'functionCall' => [Statistical::class, 'MINA'],
|
||||
'argumentCount' => '1+',
|
||||
],
|
||||
'MINIF' => [
|
||||
'MINIFS' => [
|
||||
'category' => Category::CATEGORY_STATISTICAL,
|
||||
'functionCall' => [Statistical::class, 'MINIF'],
|
||||
'argumentCount' => '2+',
|
||||
'functionCall' => [Statistical::class, 'MINIFS'],
|
||||
'argumentCount' => '3+',
|
||||
],
|
||||
'MINUTE' => [
|
||||
'category' => Category::CATEGORY_DATE_AND_TIME,
|
||||
|
|
|
@ -1134,6 +1134,68 @@ class Statistical
|
|||
return $returnValue;
|
||||
}
|
||||
|
||||
/**
|
||||
* COUNTIFS.
|
||||
*
|
||||
* Counts the number of cells that contain numbers within the list of arguments
|
||||
*
|
||||
* Excel Function:
|
||||
* COUNTIFS(criteria_range1, criteria1, [criteria_range2, criteria2]…)
|
||||
*
|
||||
* @category Statistical Functions
|
||||
*
|
||||
* @param mixed $args Criterias
|
||||
*
|
||||
* @return int
|
||||
*/
|
||||
public static function COUNTIFS(...$args)
|
||||
{
|
||||
$arrayList = $args;
|
||||
|
||||
// Return value
|
||||
$returnValue = 0;
|
||||
|
||||
if (!$arrayList) {
|
||||
return $returnValue;
|
||||
}
|
||||
|
||||
$aArgsArray = [];
|
||||
$conditions = [];
|
||||
|
||||
while (count($arrayList) > 0) {
|
||||
$aArgsArray[] = Functions::flattenArray(array_shift($arrayList));
|
||||
$conditions[] = Functions::ifCondition(array_shift($arrayList));
|
||||
}
|
||||
|
||||
// Loop through each arg and see if arguments and conditions are true
|
||||
foreach (array_keys($aArgsArray[0]) as $index) {
|
||||
$valid = true;
|
||||
|
||||
foreach ($conditions as $cidx => $condition) {
|
||||
$arg = $aArgsArray[$cidx][$index];
|
||||
|
||||
// Loop through arguments
|
||||
if (!is_numeric($arg)) {
|
||||
$arg = Calculation::wrapResult(strtoupper($arg));
|
||||
}
|
||||
$testCondition = '=' . $arg . $condition;
|
||||
if (!Calculation::getInstance()->_calculateFormulaValue($testCondition)) {
|
||||
// Is not a value within our criteria
|
||||
$valid = false;
|
||||
|
||||
break; // if false found, don't need to check other conditions
|
||||
}
|
||||
}
|
||||
|
||||
if ($valid) {
|
||||
++$returnValue;
|
||||
}
|
||||
}
|
||||
|
||||
// Return
|
||||
return $returnValue;
|
||||
}
|
||||
|
||||
/**
|
||||
* COVAR.
|
||||
*
|
||||
|
@ -2105,44 +2167,61 @@ class Statistical
|
|||
}
|
||||
|
||||
/**
|
||||
* MAXIF.
|
||||
* MAXIFS.
|
||||
*
|
||||
* Counts the maximum value within a range of cells that contain numbers within the list of arguments
|
||||
*
|
||||
* Excel Function:
|
||||
* MAXIF(value1[,value2[, ...]],condition)
|
||||
* MAXIFS(max_range, criteria_range1, criteria1, [criteria_range2, criteria2], ...)
|
||||
*
|
||||
* @category Mathematical and Trigonometric Functions
|
||||
* @category Statistical Functions
|
||||
*
|
||||
* @param mixed $aArgs Data values
|
||||
* @param string $condition the criteria that defines which cells will be checked
|
||||
* @param mixed $sumArgs
|
||||
* @param mixed $args Data range and criterias
|
||||
*
|
||||
* @return float
|
||||
*/
|
||||
public static function MAXIF($aArgs, $condition, $sumArgs = [])
|
||||
public static function MAXIFS(...$args)
|
||||
{
|
||||
$arrayList = $args;
|
||||
|
||||
// Return value
|
||||
$returnValue = null;
|
||||
|
||||
$aArgs = Functions::flattenArray($aArgs);
|
||||
$sumArgs = Functions::flattenArray($sumArgs);
|
||||
if (empty($sumArgs)) {
|
||||
$sumArgs = $aArgs;
|
||||
$maxArgs = Functions::flattenArray(array_shift($arrayList));
|
||||
$aArgsArray = [];
|
||||
$conditions = [];
|
||||
|
||||
while (count($arrayList) > 0) {
|
||||
$aArgsArray[] = Functions::flattenArray(array_shift($arrayList));
|
||||
$conditions[] = Functions::ifCondition(array_shift($arrayList));
|
||||
}
|
||||
$condition = Functions::ifCondition($condition);
|
||||
// Loop through arguments
|
||||
foreach ($aArgs as $key => $arg) {
|
||||
if (!is_numeric($arg)) {
|
||||
$arg = Calculation::wrapResult(strtoupper($arg));
|
||||
}
|
||||
$testCondition = '=' . $arg . $condition;
|
||||
if (Calculation::getInstance()->_calculateFormulaValue($testCondition)) {
|
||||
if (($returnValue === null) || ($arg > $returnValue)) {
|
||||
$returnValue = $arg;
|
||||
|
||||
// Loop through each arg and see if arguments and conditions are true
|
||||
foreach ($maxArgs as $index => $value) {
|
||||
$valid = true;
|
||||
|
||||
foreach ($conditions as $cidx => $condition) {
|
||||
$arg = $aArgsArray[$cidx][$index];
|
||||
|
||||
// Loop through arguments
|
||||
if (!is_numeric($arg)) {
|
||||
$arg = Calculation::wrapResult(strtoupper($arg));
|
||||
}
|
||||
$testCondition = '=' . $arg . $condition;
|
||||
if (!Calculation::getInstance()->_calculateFormulaValue($testCondition)) {
|
||||
// Is not a value within our criteria
|
||||
$valid = false;
|
||||
|
||||
break; // if false found, don't need to check other conditions
|
||||
}
|
||||
}
|
||||
|
||||
if ($valid) {
|
||||
$returnValue = $returnValue === null ? $value : max($value, $returnValue);
|
||||
}
|
||||
}
|
||||
|
||||
// Return
|
||||
return $returnValue;
|
||||
}
|
||||
|
||||
|
@ -2268,44 +2347,61 @@ class Statistical
|
|||
}
|
||||
|
||||
/**
|
||||
* MINIF.
|
||||
* MINIFS.
|
||||
*
|
||||
* Returns the minimum value within a range of cells that contain numbers within the list of arguments
|
||||
*
|
||||
* Excel Function:
|
||||
* MINIF(value1[,value2[, ...]],condition)
|
||||
* MINIFS(min_range, criteria_range1, criteria1, [criteria_range2, criteria2], ...)
|
||||
*
|
||||
* @category Mathematical and Trigonometric Functions
|
||||
* @category Statistical Functions
|
||||
*
|
||||
* @param mixed $aArgs Data values
|
||||
* @param string $condition the criteria that defines which cells will be checked
|
||||
* @param mixed $sumArgs
|
||||
* @param mixed $args Data range and criterias
|
||||
*
|
||||
* @return float
|
||||
*/
|
||||
public static function MINIF($aArgs, $condition, $sumArgs = [])
|
||||
public static function MINIFS(...$args)
|
||||
{
|
||||
$arrayList = $args;
|
||||
|
||||
// Return value
|
||||
$returnValue = null;
|
||||
|
||||
$aArgs = Functions::flattenArray($aArgs);
|
||||
$sumArgs = Functions::flattenArray($sumArgs);
|
||||
if (empty($sumArgs)) {
|
||||
$sumArgs = $aArgs;
|
||||
$minArgs = Functions::flattenArray(array_shift($arrayList));
|
||||
$aArgsArray = [];
|
||||
$conditions = [];
|
||||
|
||||
while (count($arrayList) > 0) {
|
||||
$aArgsArray[] = Functions::flattenArray(array_shift($arrayList));
|
||||
$conditions[] = Functions::ifCondition(array_shift($arrayList));
|
||||
}
|
||||
$condition = Functions::ifCondition($condition);
|
||||
// Loop through arguments
|
||||
foreach ($aArgs as $key => $arg) {
|
||||
if (!is_numeric($arg)) {
|
||||
$arg = Calculation::wrapResult(strtoupper($arg));
|
||||
}
|
||||
$testCondition = '=' . $arg . $condition;
|
||||
if (Calculation::getInstance()->_calculateFormulaValue($testCondition)) {
|
||||
if (($returnValue === null) || ($arg < $returnValue)) {
|
||||
$returnValue = $arg;
|
||||
|
||||
// Loop through each arg and see if arguments and conditions are true
|
||||
foreach ($minArgs as $index => $value) {
|
||||
$valid = true;
|
||||
|
||||
foreach ($conditions as $cidx => $condition) {
|
||||
$arg = $aArgsArray[$cidx][$index];
|
||||
|
||||
// Loop through arguments
|
||||
if (!is_numeric($arg)) {
|
||||
$arg = Calculation::wrapResult(strtoupper($arg));
|
||||
}
|
||||
$testCondition = '=' . $arg . $condition;
|
||||
if (!Calculation::getInstance()->_calculateFormulaValue($testCondition)) {
|
||||
// Is not a value within our criteria
|
||||
$valid = false;
|
||||
|
||||
break; // if false found, don't need to check other conditions
|
||||
}
|
||||
}
|
||||
|
||||
if ($valid) {
|
||||
$returnValue = $returnValue === null ? $value : min($value, $returnValue);
|
||||
}
|
||||
}
|
||||
|
||||
// Return
|
||||
return $returnValue;
|
||||
}
|
||||
|
||||
|
|
|
@ -224,6 +224,7 @@ LOWER
|
|||
MATCH
|
||||
MAX
|
||||
MAXA
|
||||
MAXIFS
|
||||
MDETERM
|
||||
MDURATION
|
||||
MEDIAN
|
||||
|
@ -231,6 +232,7 @@ MID
|
|||
MIDB
|
||||
MIN
|
||||
MINA
|
||||
MINIFS
|
||||
MINUTE
|
||||
MINVERSE
|
||||
MIRR
|
||||
|
|
|
@ -0,0 +1,63 @@
|
|||
<?php
|
||||
|
||||
namespace PhpOffice\PhpSpreadsheetTests\Calculation;
|
||||
|
||||
use PhpOffice\PhpSpreadsheet\Calculation\Functions;
|
||||
use PhpOffice\PhpSpreadsheet\Calculation\Statistical;
|
||||
use PHPUnit\Framework\TestCase;
|
||||
|
||||
class StatisticalTest extends TestCase
|
||||
{
|
||||
public function setUp()
|
||||
{
|
||||
Functions::setCompatibilityMode(Functions::COMPATIBILITY_EXCEL);
|
||||
}
|
||||
|
||||
/**
|
||||
* @dataProvider providerCOUNTIFS
|
||||
*
|
||||
* @param mixed $expectedResult
|
||||
*/
|
||||
public function testCOUNTIFS($expectedResult, ...$args)
|
||||
{
|
||||
$result = Statistical::COUNTIFS(...$args);
|
||||
self::assertEquals($expectedResult, $result, '', 1E-12);
|
||||
}
|
||||
|
||||
public function providerCOUNTIFS()
|
||||
{
|
||||
return require 'data/Calculation/Statistical/COUNTIFS.php';
|
||||
}
|
||||
|
||||
/**
|
||||
* @dataProvider providerMAXIFS
|
||||
*
|
||||
* @param mixed $expectedResult
|
||||
*/
|
||||
public function testMAXIFS($expectedResult, ...$args)
|
||||
{
|
||||
$result = Statistical::MAXIFS(...$args);
|
||||
self::assertEquals($expectedResult, $result, '', 1E-12);
|
||||
}
|
||||
|
||||
public function providerMAXIFS()
|
||||
{
|
||||
return require 'data/Calculation/Statistical/MAXIFS.php';
|
||||
}
|
||||
|
||||
/**
|
||||
* @dataProvider providerMINIFS
|
||||
*
|
||||
* @param mixed $expectedResult
|
||||
*/
|
||||
public function testMINIFS($expectedResult, ...$args)
|
||||
{
|
||||
$result = Statistical::MINIFS(...$args);
|
||||
self::assertEquals($expectedResult, $result, '', 1E-12);
|
||||
}
|
||||
|
||||
public function providerMINIFS()
|
||||
{
|
||||
return require 'data/Calculation/Statistical/MINIFS.php';
|
||||
}
|
||||
}
|
|
@ -0,0 +1,32 @@
|
|||
<?php
|
||||
|
||||
return [
|
||||
[
|
||||
2,
|
||||
[
|
||||
['Y'],
|
||||
['Y'],
|
||||
['N'],
|
||||
],
|
||||
'=Y',
|
||||
],
|
||||
[
|
||||
3,
|
||||
[
|
||||
['A'],
|
||||
['B'],
|
||||
['C'],
|
||||
['B'],
|
||||
['B'],
|
||||
],
|
||||
'=B',
|
||||
[
|
||||
['C'],
|
||||
['B'],
|
||||
['A'],
|
||||
['B'],
|
||||
['B'],
|
||||
],
|
||||
'=B',
|
||||
],
|
||||
];
|
|
@ -0,0 +1,44 @@
|
|||
<?php
|
||||
|
||||
return [
|
||||
[
|
||||
2,
|
||||
[
|
||||
[1],
|
||||
[2],
|
||||
[3],
|
||||
],
|
||||
[
|
||||
['Y'],
|
||||
['Y'],
|
||||
['N'],
|
||||
],
|
||||
'=Y',
|
||||
[
|
||||
['H'],
|
||||
['H'],
|
||||
['H'],
|
||||
],
|
||||
'=H',
|
||||
],
|
||||
[
|
||||
2,
|
||||
[
|
||||
[1],
|
||||
[2],
|
||||
[3],
|
||||
],
|
||||
[
|
||||
['A'],
|
||||
['B'],
|
||||
['C'],
|
||||
],
|
||||
'=B',
|
||||
[
|
||||
['C'],
|
||||
['B'],
|
||||
['A'],
|
||||
],
|
||||
'=B',
|
||||
],
|
||||
];
|
|
@ -0,0 +1,44 @@
|
|||
<?php
|
||||
|
||||
return [
|
||||
[
|
||||
1,
|
||||
[
|
||||
[1],
|
||||
[2],
|
||||
[3],
|
||||
],
|
||||
[
|
||||
['Y'],
|
||||
['Y'],
|
||||
['N'],
|
||||
],
|
||||
'=Y',
|
||||
[
|
||||
['H'],
|
||||
['H'],
|
||||
['H'],
|
||||
],
|
||||
'=H',
|
||||
],
|
||||
[
|
||||
2,
|
||||
[
|
||||
[1],
|
||||
[2],
|
||||
[3],
|
||||
],
|
||||
[
|
||||
['A'],
|
||||
['B'],
|
||||
['C'],
|
||||
],
|
||||
'=B',
|
||||
[
|
||||
['C'],
|
||||
['B'],
|
||||
['A'],
|
||||
],
|
||||
'=B',
|
||||
],
|
||||
];
|
Loading…
Reference in New Issue