VLOOKUP function

This article describes the formula syntax and usage of the VLOOKUP function (function: A prewritten formula that takes a value or values, performs an operation, and returns a value or values. Use functions to simplify and shorten formulas on a worksheet, especially those that perform lengthy or complex calculations.) in Microsoft Office Excel.

Description

You can use the VLOOKUP function to search the first column of a range (range: Two or more cells on a sheet. The cells in a range can be adjacent or nonadjacent.) of cells, and then return a value from any cell on the same row of the range. For example, suppose that you have a list of employees contained in the range A2:C10. The employees' ID numbers are stored in the first column of the range, as shown in the following illustration.

A range of cells on a worksheet

If you know the employee's ID number, you can use the VLOOKUP function to return either the department or the name of that employee. To obtain the name of employee number 38, you can use the formula =VLOOKUP(38, A2:C10, 3, FALSE). This formula searches for the value 38 in the first column of the range A2:C10, and then returns the value that is contained in the third column of the range and on the same row as the lookup value ("Axel Delgado").

The V in VLOOKUP stands for vertical. Use VLOOKUP instead of HLOOKUP when your comparison values are located in a column to the left of the data that you want to find.

Syntax

VLOOKUP(lookup_value, table_array, col_index_num, [range_lookup])

The VLOOKUP function syntax has the following arguments (argument: A value that provides information to an action, an event, a method, a property, a function, or a procedure.):

  • lookup_value    Required. The value to search in the first column of the table or range. The lookup_value argument can be a value or a reference. If the value you supply for the lookup_value argument is smaller than the smallest value in the first column of the table_array argument, VLOOKUP returns the #N/A error value.
  • table_array    Required. The range of cells that contains the data. You can use a reference to a range (for example, A2:D8), or a range name. The values in the first column of table_array are the values searched by lookup_value. These values can be text, numbers, or logical values. Uppercase and lowercase text are equivalent.
  • col_index_num    Required. The column number in the table_array argument from which the matching value must be returned. A col_index_num argument of 1 returns the value in the first column in table_array; a col_index_num of 2 returns the value in the second column in table_array, and so on.

If the col_index_num argument is:

  • Less than 1, VLOOKUP returns the #VALUE! error value.
  • Greater than the number of columns in table_array, VLOOKUP returns the #REF! error value.
  • range_lookup    Optional. A logical value that specifies whether you want VLOOKUP to find an exact match or an approximate match:
  • If range_lookup is either TRUE or is omitted, an exact or approximate match is returned. If an exact match is not found, the next largest value that is less than lookup_value is returned.

 Important   If range_lookup is either TRUE or is omitted, the values in the first column of table_array must be placed in ascending sort order; otherwise, VLOOKUP might not return the correct value.

For more information, see Sort data.

If range_lookup is FALSE, the values in the first column of table_array do not need to be sorted.

  • If the range_lookup argument is FALSE, VLOOKUP will find only an exact match. If there are two or more values in the first column of table_array that match the lookup_value, the first value found is used. If an exact match is not found, the error value #N/A is returned.

Example 1

The example may be easier to understand if you copy it to a blank worksheet.

ShowHow do I copy an example?

  1. Select the example in this article. If you are copying the example in Excel Web App, copy and paste one cell at a time.Important Do not select the row or column headers.

Selecting an example from Help

Selecting an example from Help

  1. Press CTRL+C.
  2. Create a blank workbook or worksheet.
  3. In the worksheet, select cell A1, and press CTRL+V. If you are working in Excel Web App, repeat copying and pasting for each cell in the example.

Important For the example to work properly, you must paste it into cell A1 of the worksheet.

  1. To switch between viewing the results and viewing the formulas that return the results, press CTRL+` (grave accent), or on the Formulas tab, in the Formula Auditing group, click the Show Formulas button.

After you copy the example to a blank worksheet, you can adapt it to suit your needs.


This example searches the Density column of an atmospheric properties table to find corresponding values in the Viscosity and Temperature columns. (The values are for air at 0 degrees Celsius at sea level, or 1 atmosphere.)

 
1
2
3
4
5
6
7
8
9
10
11






12






13




14




15






16
A B C
Density Viscosity Temperature
0.457 3.55 500
0.525 3.25 400
0.606 2.93 300
0.675 2.75 250
0.746 2.57 200
0.835 2.38 150
0.946 2.17 100
1.09 1.95 50
1.29 1.71 0
Formula Description Result
=VLOOKUP(1,A2:C10,2) Using an approximate match, searches for the value 1 in column A, finds the largest value less than or equal to 1 in column A which is 0.946, and then returns the value from column B in the same row. 2.17
=VLOOKUP(1,A2:C10,3,TRUE) Using an approximate match, searches for the value 1 in column A, finds the largest value less than or equal to 1 in column A, which is 0.946, and then returns the value from column C in the same row. 100
=VLOOKUP(0.7,A2:C10,3,FALSE) Using an exact match, searches for the value 0.7 in column A. Because there is no exact match in column A, an error is returned. #N/A
=VLOOKUP(0.1,A2:C10,2,TRUE) Using an approximate match, searches for the value 0.1 in column A. Because 0.1 is less than the smallest value in column A, an error is returned. #N/A
=VLOOKUP(2,A2:C10,2,TRUE) Using an approximate match, searches for the value 2 in column A, finds the largest value less than or equal to 2 in column A, which is 1.29, and then returns the value from column B in the same row. 1.71

Example 2

The example may be easier to understand if you copy it to a blank worksheet.

ShowHow do I copy an example?

  1. Select the example in this article. If you are copying the example in Excel Web App, copy and paste one cell at a time.Important Do not select the row or column headers.

Selecting an example from Help

Selecting an example from Help

  1. Press CTRL+C.
  2. Create a blank workbook or worksheet.
  3. In the worksheet, select cell A1, and press CTRL+V. If you are working in Excel Web App, repeat copying and pasting for each cell in the example.

Important For the example to work properly, you must paste it into cell A1 of the worksheet.

  1. To switch between viewing the results and viewing the formulas that return the results, press CTRL+` (grave accent), or on the Formulas tab, in the Formula Auditing group, click the Show Formulas button.

After you copy the example to a blank worksheet, you can adapt it to suit your needs.


This example searches the Item-ID column of a baby products table and matches values in the Cost and Markup columns to calculate prices and test conditions.

 
1
2
3
4
5
6
7



8




9





10






11
A B C D
Item-ID Item Cost Markup
ST-340 Stroller $145.67 30%
BI-567 Bib $3.56 40%
DI-328 Diapers $21.45 35%
WI-989 Wipes $5.12 40%
AS-469 Aspirator $2.56 45%
Formula Description Result
= VLOOKUP("DI-328", A2:D6, 3, FALSE) * (1 + VLOOKUP("DI-328", A2:D6, 4, FALSE)) Calculates the retail price of diapers by adding the markup percentage to the cost. $28.96
= (VLOOKUP("WI-989", A2:D6, 3, FALSE) * (1 + VLOOKUP("WI-989", A2:D6, 4, FALSE))) * (1 - 20%) Calculates the sale price of wipes by subtracting a specified discount from the retail price. $5.73
= IF(VLOOKUP(A2, A2:D6, 3, FALSE) >= 20, "Markup is " & 100 * VLOOKUP(A2, A2:D6, 4, FALSE) &"%", "Cost is under $20.00") If the cost of an item is greater than or equal to $20.00, displays the string "Markup is nn%"; otherwise, displays the string "Cost is under $20.00". Markup is 30%
= IF(VLOOKUP(A3, A2:D6, 3, FALSE) >= 20, "Markup is: " & 100 * VLOOKUP(A3, A2:D6, 4, FALSE) &"%", "Cost is $" & VLOOKUP(A3, A2:D6, 3, FALSE)) If the cost of an item is greater than or equal to $20.00, displays the string Markup is nn%"; otherwise, displays the string "Cost is $n.nn". Cost is $3.56

Example 3

The example may be easier to understand if you copy it to a blank worksheet.

ShowHow do I copy an example?

  1. Select the example in this article. If you are copying the example in Excel Web App, copy and paste one cell at a time.Important Do not select the row or column headers.

Selecting an example from Help

Selecting an example from Help

  1. Press CTRL+C.
  2. Create a blank workbook or worksheet.
  3. In the worksheet, select cell A1, and press CTRL+V. If you are working in Excel Web App, repeat copying and pasting for each cell in the example.

Important For the example to work properly, you must paste it into cell A1 of the worksheet.

  1. To switch between viewing the results and viewing the formulas that return the results, press CTRL+` (grave accent), or on the Formulas tab, in the Formula Auditing group, click the Show Formulas button.

After you copy the example to a blank worksheet, you can adapt it to suit your needs.


This example searches the ID column of an employee table and matches values in other columns to calculate ages and test for error conditions.

 

1

2

3

4

5

6

7
8






9








10








11





12
A B C D E
ID Last name First name Title Birth date
1 Davis Sara Sales Rep. 12/8/1968
2 Fontana Olivier V.P. of Sales 2/19/1952
3 Leal Karina Sales Rep. 8/30/1963
4 Patten Michael Sales Rep. 9/19/1958
5 Burke Brian Sales Mgr. 3/4/1955
6 Sousa Luis Sales Rep. 7/2/1963
Formula Description Result
=INT(YEARFRAC(DATE(2004,6,30), VLOOKUP(5,A2:E7,5, FALSE), 1)) For the fiscal year 2004, finds the age of the employee with ID equal to 5. Uses the YEARFRAC function to subtract the birth date from the fiscal year end date and displays the result as an integer using the INT function. 49
=IF(ISNA(VLOOKUP(5,A2:E7,2,FALSE)) = TRUE, "Employee not found", VLOOKUP(5,A2:E7,2,FALSE))

If there is an employee with an ID of 5, displays the employee's last name; otherwise, displays the message "Employee not found".

The ISNA function returns a TRUE value when the VLOOKUP function returns the #NA error value.

Burke
=IF(ISNA(VLOOKUP(15,A3:E8,2,FALSE)) = TRUE, "Employee not found", VLOOKUP(15,A3:E8,2,FALSE))

If there is an employee with an ID of 15, displays the employee's last name; otherwise, displays the message "Employee not found".

The ISNA function returns a TRUE value when the VLOOKUP function returns the #NA error value.

Employee not found
=VLOOKUP(4,A2:E7,3,FALSE) & " " & VLOOKUP(4,A2:E7,2,FALSE) & " is a " & VLOOKUP(4,A2:E7,4,FALSE) For the employee with an ID of 4, concatenates the values of three cells into a complete sentence. Michael Patten is a Sales Rep.

Remarks

  • When searching text values in the first column of table_array, ensure that the data in the first column of table_array does not contain leading spaces, trailing spaces, inconsistent use of straight ( ' or " ) and curly ( ‘ or “) quotation marks, or nonprinting characters. In these cases, VLOOKUP might return an incorrect or unexpected value.

For more information, see CLEAN function and TRIM function.

  • When searching number or date values, ensure that the data in the first column of table_array is not stored as text values. In this case, VLOOKUP might return an incorrect or unexpected value.

For more information, see Convert numbers stored as text to numbers.

  • If range_lookup is FALSE and lookup_value is text, you can use the wildcard characters — the question mark (?) and asterisk (*) — in lookup_value. A question mark matches any single character; an asterisk matches any sequence of characters. If you want to find an actual question mark or asterisk, type a tilde (~) preceding the character.
 
 
Applies to:
Excel 2007