You are currently offline, waiting for your internet to reconnect

Your browser is out-of-date

You need to update your browser to use the site.

Update to the latest version of Internet Explorer

How to Use VLOOKUP or HLOOKUP to find an exact match

Support for Office 2003 has ended

Microsoft ended support for Office 2003 on April 8, 2014. This change has affected your software updates and security options. Learn what this means for you and how to stay protected.

Summary
The VLOOKUP and HLOOKUP functions contain an argument called range_lookup that allows you to find an exact match to your lookup value without sorting the lookup table.

Note It is not necessary to sort the lookup table if you use therange_lookup argument correctly.
More information
The syntax of these functions are defined as follows.

VLOOKUP Function

   =VLOOKUP(lookup_value,table_array,col_index_num,range_lookup)				
where:
   Argument     Definition of argument   ---------------------------------------------------------------------   lookup_value The value to be found in the first column of the array.   table_array  The table of information in which data is looked up.   col_index    The column number in the table_array for which the                matching value should be returned.   range_lookup It is a logical value that specifies whether                you want to find an exact match or an approximate match.                If TRUE or omitted, an approximate match is returned; in                other words, if an exact match is not found, the next                largest value that is less than the lookup_value is                returned. If FALSE, VLOOKUP finds an exact match. If an                exact match is not found, the #N/A error value is returned.				
Note If range_lookup is TRUE or omitted (for an approximate match), the values in the first column of table_array must be sorted in ascendingorder. If range_lookup is FALSE (for an exact match), the table_array doesnot need to be sorted.

Example That Uses FALSE as the Range_lookup Argument

The following list contains some fruits and their respective colors. Notice that the first column is not sorted:
   A1: Fruit    B1: Color     A2: Kiwi     B2: Green    A3: Banana   B3: Yellow    A4: Grape    B4: Purple     A5: Apple    B5: Red   				
The following formula finds the color (Red) that corresponds to the fruit Apple. You can type the formula in any cell on the worksheet:
=VLOOKUP("Apple",A2:B5,2,FALSE)				
Notice that if you change the range_lookup argument to TRUE, Excel returns the #N/A error, because the first column is not sorted.

HLOOKUP Function

=HLOOKUP(lookup_value,table_array,row_index_num,range_lookup)				
where:
   Argument     Definition of argument   ---------------------------------------------------------------------   lookup_value The value to be found in the first column of the array.   table_array  The table of information in which data is looked up.   row_index    The row number in the table_array for which the                matching value should be returned.   range_lookup It is a logical value that specifies whether                you want to find an exact match or an approximate match.                If TRUE or omitted, an approximate match is returned; in                other words, if an exact match is not found, the next                largest value that is less than the lookup_value is                returned. If FALSE, VLOOKUP finds an exact match.                If an exact match is not found, the #N/A error value is                returned.				
Note If range_lookup is TRUE or omitted (for an approximate match), the values in the first row of table_array must be sorted in ascending order. If range_lookup is FALSE (for an exact match), the table_array does not need to be sorted.

Example That Uses FALSE as the Range_lookup Argument

The following list contains some fruits and their respective colors. Notice that the first column is not sorted:
   A1: Fruit    B1: Color   A2: Kiwi     B2: Green   A3: Banana   B3: Yellow   A4: Grape    B4: Purple   A5: Apple    B5: Red				
The following formula finds the Color column, and returns the third item (-1) for the heading Yellow. You can type the formula in any cell on the worksheet:
=HLOOKUP("Color",A1:B5,3,FALSE)				
Notice that if you change the range_lookup argument to TRUE, Excel returns the #N/A error, because the first column is not sorted.
References
For additional information about how to use LOOKUP functions in Microsoft Excel, click the article numbers below to view the articles in the Microsoft Knowledge Base:
181212 XL: Performing a Lookup with Unsorted Data in Excel
214264 XL: How to Perform a Case-Sensitive Lookup
214069 XL: How to Return the First or Last Match in an Array
181201 XL: HLOOKUP, VLOOKUP, LOOKUP Return Incorrect Values
213476 XL: Unexpected Results with Mixed Text and Numbers in Lookup Table
280094 XL: Sample User-Defined Function to Hide Formula Errors
For more information about the HLOOKUP function, click Microsoft Excel Help on the Help menu, type HLOOKUP worksheet function in the Office Assistant or the Answer Wizard, and then click Search to view the topic.
For more information about the VLOOKUP function, click Microsoft Excel Help on the Help menu, type VLOOKUP worksheet function in the Office Assistant or the Answer Wizard, and then click Search to view the topic.
XL2002 XL2000 XL97 XL XL2003 XL2007 XL2010
Properties

Article ID: 181213 - Last Review: 09/23/2015 05:59:00 - Revision: 8.0

  • Microsoft Excel 2002 Standard Edition
  • Microsoft Excel 2000 Standard Edition
  • Microsoft Excel 97 Standard Edition
  • Microsoft Office Excel 2003
  • Microsoft Excel 2010
  • Microsoft Office Excel 2007
  • Excel 2016
  • Microsoft Excel 2013
  • kbhowto KB181213
Feedback