MATCH function behavior when third parameter is equal to 1 or -1
Fixes #51 Closes #122
This commit is contained in:
parent
7fd5eefe04
commit
fd83c191ea
|
@ -497,93 +497,107 @@ class LookupRef
|
|||
* Excel Function:
|
||||
* =MATCH(lookup_value, lookup_array, [match_type])
|
||||
*
|
||||
* @param lookup_value The value that you want to match in lookup_array
|
||||
* @param lookup_array The range of cells being searched
|
||||
* @param match_type The number -1, 0, or 1. -1 means above, 0 means exact match, 1 means below. If match_type is 1 or -1, the list has to be ordered.
|
||||
* @param mixed $lookup_value
|
||||
* @param mixed $lookup_array
|
||||
* @param mixed $match_type
|
||||
* @param mixed $lookupValue The value that you want to match in lookup_array
|
||||
* @param mixed $lookupArray The range of cells being searched
|
||||
* @param mixed $matchType The number -1, 0, or 1. -1 means above, 0 means exact match, 1 means below. If match_type is 1 or -1, the list has to be ordered.
|
||||
*
|
||||
* @return int The relative position of the found item
|
||||
*/
|
||||
public static function MATCH($lookup_value, $lookup_array, $match_type = 1)
|
||||
public static function MATCH($lookupValue, $lookupArray, $matchType = 1)
|
||||
{
|
||||
$lookup_array = Functions::flattenArray($lookup_array);
|
||||
$lookup_value = Functions::flattenSingleValue($lookup_value);
|
||||
$match_type = (is_null($match_type)) ? 1 : (int) Functions::flattenSingleValue($match_type);
|
||||
// MATCH is not case sensitive
|
||||
$lookup_value = strtolower($lookup_value);
|
||||
$lookupArray = Functions::flattenArray($lookupArray);
|
||||
$lookupValue = Functions::flattenSingleValue($lookupValue);
|
||||
$matchType = (is_null($matchType)) ? 1 : (int) Functions::flattenSingleValue($matchType);
|
||||
|
||||
// lookup_value type has to be number, text, or logical values
|
||||
if ((!is_numeric($lookup_value)) && (!is_string($lookup_value)) && (!is_bool($lookup_value))) {
|
||||
// MATCH is not case sensitive
|
||||
$lookupValue = strtolower($lookupValue);
|
||||
|
||||
// Lookup_value type has to be number, text, or logical values
|
||||
if ((!is_numeric($lookupValue)) && (!is_string($lookupValue)) && (!is_bool($lookupValue))) {
|
||||
return Functions::NA();
|
||||
}
|
||||
|
||||
// match_type is 0, 1 or -1
|
||||
if (($match_type !== 0) && ($match_type !== -1) && ($match_type !== 1)) {
|
||||
// Match_type is 0, 1 or -1
|
||||
if (($matchType !== 0) && ($matchType !== -1) && ($matchType !== 1)) {
|
||||
return Functions::NA();
|
||||
}
|
||||
|
||||
// lookup_array should not be empty
|
||||
$lookupArraySize = count($lookup_array);
|
||||
// Lookup_array should not be empty
|
||||
$lookupArraySize = count($lookupArray);
|
||||
if ($lookupArraySize <= 0) {
|
||||
return Functions::NA();
|
||||
}
|
||||
|
||||
// lookup_array should contain only number, text, or logical values, or empty (null) cells
|
||||
foreach ($lookup_array as $i => $lookupArrayValue) {
|
||||
// Lookup_array should contain only number, text, or logical values, or empty (null) cells
|
||||
foreach ($lookupArray as $i => $lookupArrayValue) {
|
||||
// check the type of the value
|
||||
if ((!is_numeric($lookupArrayValue)) && (!is_string($lookupArrayValue)) &&
|
||||
(!is_bool($lookupArrayValue)) && (!is_null($lookupArrayValue))) {
|
||||
(!is_bool($lookupArrayValue)) && (!is_null($lookupArrayValue))
|
||||
) {
|
||||
return Functions::NA();
|
||||
}
|
||||
// convert strings to lowercase for case-insensitive testing
|
||||
// Convert strings to lowercase for case-insensitive testing
|
||||
if (is_string($lookupArrayValue)) {
|
||||
$lookup_array[$i] = strtolower($lookupArrayValue);
|
||||
$lookupArray[$i] = strtolower($lookupArrayValue);
|
||||
}
|
||||
if ((is_null($lookupArrayValue)) && (($match_type == 1) || ($match_type == -1))) {
|
||||
$lookup_array = array_slice($lookup_array, 0, $i - 1);
|
||||
if ((is_null($lookupArrayValue)) && (($matchType == 1) || ($matchType == -1))) {
|
||||
$lookupArray = array_slice($lookupArray, 0, $i - 1);
|
||||
}
|
||||
}
|
||||
|
||||
// if match_type is 1 or -1, the list has to be ordered
|
||||
if ($match_type == 1) {
|
||||
asort($lookup_array);
|
||||
$keySet = array_keys($lookup_array);
|
||||
} elseif ($match_type == -1) {
|
||||
arsort($lookup_array);
|
||||
$keySet = array_keys($lookup_array);
|
||||
if ($matchType == 1) {
|
||||
// If match_type is 1 the list has to be processed from last to first
|
||||
|
||||
$lookupArray = array_reverse($lookupArray);
|
||||
$keySet = array_reverse(array_keys($lookupArray));
|
||||
}
|
||||
|
||||
// **
|
||||
// find the match
|
||||
// **
|
||||
foreach ($lookup_array as $i => $lookupArrayValue) {
|
||||
if (($match_type == 0) && ($lookupArrayValue == $lookup_value)) {
|
||||
// exact match
|
||||
return ++$i;
|
||||
} elseif (($match_type == -1) && ($lookupArrayValue <= $lookup_value)) {
|
||||
$i = array_search($i, $keySet);
|
||||
// if match_type is -1 <=> find the smallest value that is greater than or equal to lookup_value
|
||||
if ($i < 1) {
|
||||
// 1st cell was already smaller than the lookup_value
|
||||
break;
|
||||
|
||||
if ($matchType == 0 || $matchType == 1) {
|
||||
foreach ($lookupArray as $i => $lookupArrayValue) {
|
||||
if (($matchType == 0) && ($lookupArrayValue == $lookupValue)) {
|
||||
// exact match
|
||||
return ++$i;
|
||||
} elseif (($matchType == 1) && ($lookupArrayValue <= $lookupValue)) {
|
||||
$i = array_search($i, $keySet);
|
||||
|
||||
// The current value is the (first) match
|
||||
return $i + 1;
|
||||
}
|
||||
// the previous cell was the match
|
||||
return $keySet[$i - 1] + 1;
|
||||
} elseif (($match_type == 1) && ($lookupArrayValue >= $lookup_value)) {
|
||||
$i = array_search($i, $keySet);
|
||||
// if match_type is 1 <=> find the largest value that is less than or equal to lookup_value
|
||||
if ($i < 1) {
|
||||
// 1st cell was already bigger than the lookup_value
|
||||
break;
|
||||
}
|
||||
} else {
|
||||
// matchType = -1
|
||||
|
||||
// "Special" case: since the array it's supposed to be ordered in descending order, the
|
||||
// Excel algorithm gives up immediately if the first element is smaller than the searched value
|
||||
if ($lookupArray[0] < $lookupValue) {
|
||||
return Functions::NA();
|
||||
}
|
||||
|
||||
$maxValueKey = null;
|
||||
|
||||
// The basic algorithm is:
|
||||
// Iterate and keep the highest match until the next element is smaller than the searched value.
|
||||
// Return immediately if perfect match is found
|
||||
foreach ($lookupArray as $i => $lookupArrayValue) {
|
||||
if ($lookupArrayValue == $lookupValue) {
|
||||
// Another "special" case. If a perfect match is found,
|
||||
// the algorithm gives up immediately
|
||||
return $i + 1;
|
||||
} elseif ($lookupArrayValue >= $lookupValue) {
|
||||
$maxValueKey = $i + 1;
|
||||
}
|
||||
// the previous cell was the match
|
||||
return $keySet[$i - 1] + 1;
|
||||
}
|
||||
|
||||
if ($maxValueKey !== null) {
|
||||
return $maxValueKey;
|
||||
}
|
||||
}
|
||||
|
||||
// unsuccessful in finding a match, return #N/A error value
|
||||
// Unsuccessful in finding a match, return #N/A error value
|
||||
return Functions::NA();
|
||||
}
|
||||
|
||||
|
|
|
@ -48,4 +48,21 @@ class LookupRefTest extends \PHPUnit_Framework_TestCase
|
|||
{
|
||||
return require 'data/Calculation/LookupRef/VLOOKUP.php';
|
||||
}
|
||||
|
||||
/**
|
||||
* @dataProvider providerMATCH
|
||||
* @group fail19
|
||||
*
|
||||
* @param mixed $expectedResult
|
||||
*/
|
||||
public function testMATCH($expectedResult, ...$args)
|
||||
{
|
||||
$result = LookupRef::MATCH(...$args);
|
||||
$this->assertEquals($expectedResult, $result);
|
||||
}
|
||||
|
||||
public function providerMATCH()
|
||||
{
|
||||
return require 'data/Calculation/LookupRef/MATCH.php';
|
||||
}
|
||||
}
|
||||
|
|
|
@ -0,0 +1,99 @@
|
|||
<?php
|
||||
|
||||
return [
|
||||
// Third argument = 0
|
||||
[
|
||||
1, // Expected
|
||||
2, // Input
|
||||
[2, 3, 4, 3],
|
||||
0,
|
||||
],
|
||||
[
|
||||
'#N/A', // Expected
|
||||
2, // Input
|
||||
[1, 0, 4, 3],
|
||||
0,
|
||||
],
|
||||
[
|
||||
1, // Expected
|
||||
2, // Input
|
||||
[2, 0, 0, 3],
|
||||
0,
|
||||
],
|
||||
[
|
||||
2, // Expected
|
||||
0, // Input
|
||||
[2, 0, 0, 3],
|
||||
0,
|
||||
],
|
||||
|
||||
// Third argument = 1
|
||||
[
|
||||
1, // Expected
|
||||
2, // Input
|
||||
[2, 3, 4, 3],
|
||||
1,
|
||||
],
|
||||
[
|
||||
2, // Expected
|
||||
2, // Input
|
||||
[2, 0, 4, 3],
|
||||
1,
|
||||
],
|
||||
[
|
||||
3, // Expected
|
||||
2, // Input
|
||||
[2, 0, 0, 3],
|
||||
1,
|
||||
],
|
||||
[
|
||||
4, // Expected
|
||||
4, // Input
|
||||
[2, 0, 0, 3],
|
||||
1,
|
||||
],
|
||||
|
||||
// Third argument = -1
|
||||
[
|
||||
1, // Expected
|
||||
2, // Input
|
||||
[2, 0, 0, 3],
|
||||
-1,
|
||||
],
|
||||
[
|
||||
4, // Expected
|
||||
2, // Input
|
||||
[3, 3, 4, 5],
|
||||
-1,
|
||||
],
|
||||
[
|
||||
1, // Expected
|
||||
5, // Input
|
||||
[8, 4, 3, 2],
|
||||
-1,
|
||||
],
|
||||
[
|
||||
'#N/A', // Expected
|
||||
6, // Input
|
||||
[3, 5, 6, 8],
|
||||
-1,
|
||||
],
|
||||
[
|
||||
1, // Expected
|
||||
6, // Input
|
||||
[8, 5, 4, 2],
|
||||
-1,
|
||||
],
|
||||
[
|
||||
3, // Expected
|
||||
4, // Input
|
||||
[5, 8, 4, 2],
|
||||
-1,
|
||||
],
|
||||
[
|
||||
2, // Expected
|
||||
4, // Input
|
||||
[8, 8, 3, 2],
|
||||
-1,
|
||||
],
|
||||
];
|
Loading…
Reference in New Issue