Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Making VLOOKUP Case Sensitive.
Written by Allen Wyatt (last updated May 4, 2022)
This tip applies to Excel 2007, 2010, 2013, and 2016
Robin asked if there is a way to do a VLOOKUP that is case sensitive. Her lookup table/range has entries that are similar (AbC and aBC) with the only difference being the case of the letters. She can't change the values (make them all upper or lower case) since the unique values are vital.
The VLOOKUP function doesn't have a way to check for the case of information; it is case insensitive. There are several ways you can work around this shortcoming, however. One way is to use the CODE function to create an intermediate column that can be searched by VLOOKUP. Assuming that your original data is in column B, you could put the following formula in cell A1 and copy it down the column:
=CODE(LEFT(B1,1))&"."&CODE(MID(B1,2,1))&"."&CODE(RIGHT(B1,1))
This formula looks at the first three characters of whatever is in cell B1 and converts those characters to decimal character codes separated by periods. Thus, if A1 contained "ABC" then B1 would contain "65.66.67". Assuming that the value you want to locate is in cell C1, you could use the following as your VLOOKUP formula:
=VLOOKUP(CODE(LEFT(C1,1))&"."&CODE(MID(C1,2,1))&"."& CODE(MID(C1,3,1)), A:B,2,)
Another approach is to use the EXACT function to determine the location of what you are looking for. This approach doesn't use VLOOKUP at all; instead, relying on the INDEX function. The formula assumes that the cells you want to compare are in column A and what you want to return is the corresponding cell in column B.
=IF(MIN(IF(EXACT(C1,$A$1:$A$100),ROW($A$1:$A$100)))=0,NA(), INDEX($B$1:$B$100,MIN(IF(EXACT(C1,$A$1:$A$100),ROW($A$1:$A$100)))))
This formula needs to be entered as an array formula (Shift+Ctrl+Enter). The first part of the formula (the first instance of EXACT) compares C1 (what you are looking for) to each value in the range A1:A100. Since this is an array formula, you end up with, in this case, 100 True/False values depending on whether there is an exact match or not. If there is a match, then the first ROW function returns the row of the match and the INDEX function is used to grab the value from column B in that row.
In some instances you might want to create your own user-defined function that will do the lookup for you. The following is an example of such a macro:
Function CaseVLook(compare_value, table_array As Range, _ Optional col_index As Integer = 1) Dim c As Range Dim rngColumn1 As Range Application.Volatile Set rngColumn1 = table_array.Columns(1) CaseVLook = "Not Found" 'Loop first column For Each c In rngColumn1.Cells If c.Value = compare_value Then CaseVLook = c.Offset(0, col_index - 1).Value Exit For End If Next c End Function
To use the macro, simply call the function with the value you want to find (say cell C1), the range whose first column should be searched (such as A:B), and optionally the offset of the column within that range, as here:
=CaseVLook(C1,A:B,2)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12222) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Making VLOOKUP Case Sensitive.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Users of the most recent versions of Excel have four different ways available to combine values into strings. Even those ...
Discover MoreTwo common worksheet functions used to count things are COUNT and COUNTA. Not understanding how these functions treat ...
Discover MoreLooking for a great reference that you can use to help figure out the various worksheet functions available in Excel? ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-10-13 10:53:34
Dave Bonin
Microsoft's solution partly works.
It guards against getting the wrong value, but doesn't guarantee we get the right value.
Unfortunately, it can fail if you are looking for "ABC" and the VLOOKUP() list contains "abc", "ABc" and "ABC".
In that case, the VLOOKUP() will find the first "abc", but never even consider the second "ABc" or the third "ABC".
The third one is the one we want.
2017-10-10 07:50:48
Peter Moran
Hi,
Here is possibly the simplest solution provided by Microsoft:
In any blank cell on the active worksheet, type the following formula:
=IF(EXACT(C1,VLOOKUP(C1,A1:B5,1,FALSE))=TRUE,VLOOKUP(C1,A1:B5,2,FALSE),"No exact match")
If the lookup value and the returned value are exact matches, use the returned value, else no good!
This formula returns "No exact match" because the lookup value in cell C1 does not use the same case as the entry in the table.
URL: https://support.microsoft.com/en-us/help/214264/xl-how-to-perform-a-case-sensitive-lookup.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments