Making VLOOKUP Case Sensitive

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)