diff --git a/CHANGELOG.md b/CHANGELOG.md index a08ff597..35d9d5cd 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -17,6 +17,7 @@ and this project adheres to [Semantic Versioning](https://semver.org). - Fix handling for escaped enclosures and new lines in CSV Separator Inference - Fix MATCH an error was appearing when comparing strings against 0 (always true) +- Fix VLOOKUP - Fix return type hint ## [1.6.0] - 2019-01-02 diff --git a/src/PhpSpreadsheet/Calculation/LookupRef.php b/src/PhpSpreadsheet/Calculation/LookupRef.php index b71313ee..e6b0f320 100644 --- a/src/PhpSpreadsheet/Calculation/LookupRef.php +++ b/src/PhpSpreadsheet/Calculation/LookupRef.php @@ -4,6 +4,7 @@ namespace PhpOffice\PhpSpreadsheet\Calculation; use PhpOffice\PhpSpreadsheet\Cell\Cell; use PhpOffice\PhpSpreadsheet\Cell\Coordinate; +use PhpOffice\PhpSpreadsheet\Shared\StringHelper; use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet; class LookupRef @@ -473,8 +474,9 @@ class LookupRef $lookupValue = Functions::flattenSingleValue($lookupValue); $matchType = ($matchType === null) ? 1 : (int) Functions::flattenSingleValue($matchType); + $initialLookupValue = $lookupValue; // MATCH is not case sensitive - $lookupValue = strtolower($lookupValue); + $lookupValue = StringHelper::strToLower($lookupValue); // Lookup_value type has to be number, text, or logical values if ((!is_numeric($lookupValue)) && (!is_string($lookupValue)) && (!is_bool($lookupValue))) { @@ -502,7 +504,7 @@ class LookupRef } // Convert strings to lowercase for case-insensitive testing if (is_string($lookupArrayValue)) { - $lookupArray[$i] = strtolower($lookupArrayValue); + $lookupArray[$i] = StringHelper::strToLower($lookupArrayValue); } if (($lookupArrayValue === null) && (($matchType == 1) || ($matchType == -1))) { $lookupArray = array_slice($lookupArray, 0, $i - 1); @@ -665,7 +667,9 @@ class LookupRef { reset($a); $firstColumn = key($a); - if (($aLower = strtolower($a[$firstColumn])) == ($bLower = strtolower($b[$firstColumn]))) { + $aLower = StringHelper::strToLower($a[$firstColumn]); + $bLower = StringHelper::strToLower($b[$firstColumn]); + if ($aLower == $bLower) { return 0; } @@ -711,11 +715,14 @@ class LookupRef uasort($lookup_array, ['self', 'vlookupSort']); } + $lookupLower = StringHelper::strToLower($lookup_value); $rowNumber = $rowValue = false; foreach ($lookup_array as $rowKey => $rowData) { + $firstLower = StringHelper::strToLower($rowData[$firstColumn]); + // break if we have passed possible keys if ((is_numeric($lookup_value) && is_numeric($rowData[$firstColumn]) && ($rowData[$firstColumn] > $lookup_value)) || - (!is_numeric($lookup_value) && !is_numeric($rowData[$firstColumn]) && (strtolower($rowData[$firstColumn]) > strtolower($lookup_value)))) { + (!is_numeric($lookup_value) && !is_numeric($rowData[$firstColumn]) && ($firstLower > $lookupLower))) { break; } // remember the last key, but only if datatypes match @@ -723,17 +730,15 @@ class LookupRef (!is_numeric($lookup_value) && !is_numeric($rowData[$firstColumn]))) { if ($not_exact_match) { $rowNumber = $rowKey; - $rowValue = $rowData[$firstColumn]; continue; - } elseif ((strtolower($rowData[$firstColumn]) == strtolower($lookup_value)) + } elseif (($firstLower == $lookupLower) // Spreadsheets software returns first exact match, // we have sorted and we might have broken key orders // we want the first one (by its initial index) && (($rowNumber == false) || ($rowKey < $rowNumber)) ) { $rowNumber = $rowKey; - $rowValue = $rowData[$firstColumn]; } } } @@ -786,8 +791,11 @@ class LookupRef // break if we have passed possible keys $bothNumeric = is_numeric($lookup_value) && is_numeric($rowData); $bothNotNumeric = !is_numeric($lookup_value) && !is_numeric($rowData); + $lookupLower = StringHelper::strToLower($lookup_value); + $rowDataLower = StringHelper::strToLower($rowData); + if (($bothNumeric && $rowData > $lookup_value) || - ($bothNotNumeric && strtolower($rowData) > strtolower($lookup_value))) { + ($bothNotNumeric && $rowDataLower > $lookupLower)) { break; } @@ -797,7 +805,7 @@ class LookupRef $rowNumber = $rowKey; continue; - } elseif (strtolower($rowData) === strtolower($lookup_value) + } elseif ($rowDataLower === $lookupLower && ($rowNumber === null || $rowKey < $rowNumber) ) { $rowNumber = $rowKey; diff --git a/tests/data/Calculation/LookupRef/LOOKUP.php b/tests/data/Calculation/LookupRef/LOOKUP.php index 667d7fd1..a39f5e9a 100644 --- a/tests/data/Calculation/LookupRef/LOOKUP.php +++ b/tests/data/Calculation/LookupRef/LOOKUP.php @@ -106,6 +106,21 @@ return [ ['author_100'], ['author_101'] ] + ], + + [ + '#N/A', + '10y2', + [ + ['5y-1'], + ['10y1'], + ['10y2'], + ], + [ + [2.0], + [7.0], + [10.0], + ], ] ]; diff --git a/tests/data/Calculation/LookupRef/VLOOKUP.php b/tests/data/Calculation/LookupRef/VLOOKUP.php index 1ba30a47..95c1ce5a 100644 --- a/tests/data/Calculation/LookupRef/VLOOKUP.php +++ b/tests/data/Calculation/LookupRef/VLOOKUP.php @@ -311,5 +311,17 @@ return [ ], 2, false + ], + + [ + '#N/A', + '10y2', + [ + ['5y-1', 2.0], + ['10y1', 7.0], + ['10y2', 10.0] + ], + 2.0 ] + ];