From dfc74f8b95e6a3d7ec29794911c846d90d4d0ad4 Mon Sep 17 00:00:00 2001 From: Mark Baker Date: Fri, 14 Jun 2013 23:57:50 +0100 Subject: [PATCH] Feature: (amerov) - Implementation of the Excel HLOOKUP() function --- Classes/PHPExcel/Calculation.php | 2 +- Classes/PHPExcel/Calculation/LookupRef.php | 66 ++++++++++++++++++- changelog.txt | 2 +- .../PHPExcel/Calculation/LookupRefTest.php | 34 ++++++++++ .../Calculation/LookupRef/HLOOKUP.data | 9 +++ 5 files changed, 110 insertions(+), 3 deletions(-) create mode 100644 unitTests/Classes/PHPExcel/Calculation/LookupRefTest.php create mode 100644 unitTests/rawTestData/Calculation/LookupRef/HLOOKUP.data diff --git a/Classes/PHPExcel/Calculation.php b/Classes/PHPExcel/Calculation.php index 0e6e2306..a3f7be2c 100644 --- a/Classes/PHPExcel/Calculation.php +++ b/Classes/PHPExcel/Calculation.php @@ -841,7 +841,7 @@ class PHPExcel_Calculation { 'argumentCount' => '1,2' ), 'HLOOKUP' => array('category' => PHPExcel_Calculation_Function::CATEGORY_LOOKUP_AND_REFERENCE, - 'functionCall' => 'PHPExcel_Calculation_Functions::DUMMY', + 'functionCall' => 'PHPExcel_Calculation_LookupRef::HLOOKUP', 'argumentCount' => '3,4' ), 'HOUR' => array('category' => PHPExcel_Calculation_Function::CATEGORY_DATE_AND_TIME, diff --git a/Classes/PHPExcel/Calculation/LookupRef.php b/Classes/PHPExcel/Calculation/LookupRef.php index 96f60206..c3a3f074 100644 --- a/Classes/PHPExcel/Calculation/LookupRef.php +++ b/Classes/PHPExcel/Calculation/LookupRef.php @@ -721,7 +721,8 @@ class PHPExcel_Calculation_LookupRef { $rowNumber = $rowValue = False; foreach($lookup_array as $rowKey => $rowData) { - if (strtolower($rowData[$firstColumn]) > strtolower($lookup_value)) { + 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)))) { break; } $rowNumber = $rowKey; @@ -742,6 +743,69 @@ class PHPExcel_Calculation_LookupRef { } // function VLOOKUP() +/** + * HLOOKUP + * The HLOOKUP function searches for value in the top-most row of lookup_array and returns the value in the same column based on the index_number. + * @param lookup_value The value that you want to match in lookup_array + * @param lookup_array The range of cells being searched + * @param index_number The row number in table_array from which the matching value must be returned. The first row is 1. + * @param not_exact_match Determines if you are looking for an exact match based on lookup_value. + * @return mixed The value of the found cell + */ + public static function HLOOKUP($lookup_value, $lookup_array, $index_number, $not_exact_match=true) { + $lookup_value = PHPExcel_Calculation_Functions::flattenSingleValue($lookup_value); + $index_number = PHPExcel_Calculation_Functions::flattenSingleValue($index_number); + $not_exact_match = PHPExcel_Calculation_Functions::flattenSingleValue($not_exact_match); + + // index_number must be greater than or equal to 1 + if ($index_number < 1) { + return PHPExcel_Calculation_Functions::VALUE(); + } + + // index_number must be less than or equal to the number of columns in lookup_array + if ((!is_array($lookup_array)) || (empty($lookup_array))) { + return PHPExcel_Calculation_Functions::REF(); + } else { + $f = array_keys($lookup_array); + $firstRow = array_pop($f); + if ((!is_array($lookup_array[$firstRow])) || ($index_number > count($lookup_array[$firstRow]))) { + return PHPExcel_Calculation_Functions::REF(); + } else { + $columnKeys = array_keys($lookup_array[$firstRow]); + $firstkey = $f[0] - 1; + $returnColumn = $firstkey + $index_number; + $firstColumn = array_shift($f); + } + } + + if (!$not_exact_match) { + $firstRowH = asort($lookup_array[$firstColumn]); + } + + $rowNumber = $rowValue = False; + foreach($lookup_array[$firstColumn] as $rowKey => $rowData) { + if ((is_numeric($lookup_value) && is_numeric($rowData) && ($rowData > $lookup_value)) || + (!is_numeric($lookup_value) && !is_numeric($rowData) && (strtolower($rowData) > strtolower($lookup_value)))) { + break; + } + $rowNumber = $rowKey; + $rowValue = $rowData; + } + + if ($rowNumber !== false) { + if ((!$not_exact_match) && ($rowValue != $lookup_value)) { + // if an exact match is required, we have what we need to return an appropriate response + return PHPExcel_Calculation_Functions::NA(); + } else { + // otherwise return the appropriate value + return $lookup_array[$returnColumn][$rowNumber]; + } + } + + return PHPExcel_Calculation_Functions::NA(); + } // function HLOOKUP() + + /** * LOOKUP * The LOOKUP function searches for value either from a one-row or one-column range or from an array. diff --git a/changelog.txt b/changelog.txt index ff274946..3c27a1b2 100644 --- a/changelog.txt +++ b/changelog.txt @@ -27,7 +27,7 @@ Fixed in develop branch for release v1.7.9a: - Bugfix: (MBaker) Work item 19830 - Undefined variable: fileHandle in CSV Reader - Bugfix: (MBaker) - Style error with merged cells in PDF Writer - Bugfix: (MBaker) - Problem with cloning worksheets - +- Feature: (amerov) - Implementation of the Excel HLOOKUP() function Fixed in develop branch for release v1.7.9: - Feature: (MBaker) Include charts option for HTML Writer diff --git a/unitTests/Classes/PHPExcel/Calculation/LookupRefTest.php b/unitTests/Classes/PHPExcel/Calculation/LookupRefTest.php new file mode 100644 index 00000000..bc634317 --- /dev/null +++ b/unitTests/Classes/PHPExcel/Calculation/LookupRefTest.php @@ -0,0 +1,34 @@ +assertEquals($expectedResult, $result); + } + + public function providerHLOOKUP() + { + return new testDataFileIterator('rawTestData/Calculation/LookupRef/HLOOKUP.data'); + } + +} diff --git a/unitTests/rawTestData/Calculation/LookupRef/HLOOKUP.data b/unitTests/rawTestData/Calculation/LookupRef/HLOOKUP.data new file mode 100644 index 00000000..c29fdc95 --- /dev/null +++ b/unitTests/rawTestData/Calculation/LookupRef/HLOOKUP.data @@ -0,0 +1,9 @@ +10251, {"Order ID"|10247|10249|10250|10251|10252|10253;"Unit Price"|14.00|18.60|7.70|16.80|16.80|64.80;"Quantity"|12|9|10|6|20|40}, 2, FALSE, 16.8 +10251, {"Order ID"|10247|10249|10250|10251|10252|10253;"Unit Price"|14.00|18.60|7.70|16.80|16.80|64.80;"Quantity"|12|9|10|6|20|40}, 3, FALSE, 6.0 +10248, {"Order ID"|10247|10249|10250|10251|10252|10253;"Unit Price"|14.00|18.60|7.70|16.80|16.80|64.80;"Quantity"|12|9|10|6|20|40}, 2, FALSE, "#N/A" +10248, {"Order ID"|10247|10249|10250|10251|10252|10253;"Unit Price"|14.00|18.60|7.70|16.80|16.80|64.80;"Quantity"|12|9|10|6|20|40}, 2, TRUE, 14.0 +"Axles", {"Axles"|"Bearings"|"Bolts";4|4|9;5|7|10;6|8|11}, 2, TRUE, 4 +"Bearings", {"Axles"|"Bearings"|"Bolts";4|4|9;5|7|10;6|8|11}, 3, FALSE, 7 +"B", {"Axles"|"Bearings"|"Bolts";4|4|9;5|7|10;6|8|11}, 3, TRUE, 5 +"Bolts", {"Axles"|"Bearings"|"Bolts";4|4|9;5|7|10;6|8|11}, 4, 11 +3, {1|2|3;"a"|"b"|"c";"d"|"e"|"f"}, 2, TRUE, "c"