XL: Unexpected Results with Mixed Text & Numbers in Lookup Table

Last reviewed: February 3, 1998
Article ID: Q113261
The information in this article applies to:
  • Microsoft Excel for Windows, versions 4.0, 5.0
  • Microsoft Excel for the Macintosh, versions 4.0, 5.0
  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel 97 for Windows

SYMPTOMS

In Microsoft Excel, when you create a lookup table, the lookup functions may return the #N/A error value, or, if you are using the functions in a Microsoft Visual Basic for Applications procedure or macro, you may receive a "type mismatch" error, even though the values in the lookup table are sorted in ascending order and the value being looked up appears to fall within the range of the lookup table values.

CAUSE

When you look up a text value, Microsoft Excel looks only at the text values in your table. Similarly, when you look up a numeric value, Microsoft looks only at the numeric values.

STATUS

This behavior is by design.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

   http://www.microsoft.com/support/supportnet/refguide/default.asp

If the first column (VLOOKUP) or row (HLOOKUP) of your lookup table contains both text and numeric values, you can use Microsoft Excel to sort your table in ascending order. In this case, the numeric values will appear at the beginning of the table and the text values will appear at the end of the table. Both text and numbers are then sorted as expected. For example, the following values:

   A1: 3
   A2: 1
   A3: c
   A4: 2
   A5: d
   A6: b

will be sorted as:

   A1: 1
   A2: 2
   A3: 3
   A4: b
   A5: c
   A6: d

However, if you attempt to use a lookup function to locate a text value that is less than the first text value, the lookup the function returns the #N/A error value.

It may appear that =VLOOKUP("a",A1:A6,1) should return the value 3, which is the largest value that is less than the lookup value a. However, the formula returns the #N/A error value instead. This behavior also occurs with HLOOKUP(), LOOKUP(), and MATCH() with Match Type arguments of 1 or negative one -1.

The same behavior also holds true if you attempt to look up a numeric value that is less than the first numeric value in your lookup table.

Sample Visual Basic Macro Using VLookup

   Sub test()
      MsgBox Application. _
      VLookup("a", Workbooks("book1.xls"). _
      Worksheets("sheet1").Range("hi"), 1, False)
   End Sub

Note that in order to test this sample macro, you must create a range on sheet1 in book1 similar to the sample range above, and you must give the range the defined name "hi" (without the quotation marks).

WORKAROUNDS

Method 1: Include Minimum and Maximum Values for Both Text and Numbers

If you want your lookup table to be split into separate tables for text and numbers (the default), you must include minimum values for both the text and the numeric values in your lookup table.

Zero is the lowest positive integer and the blank space character is the lowest printable text character.

Method 2: Format All Cells as Text

If you want the table to behave the way it appears after it is sorted by Microsoft Excel, such that it returns the highest numeric value if a text value is looked up, then you must treat your table as text only. The following are two ways to do this:

  • Enter every cell in your table as text. Numeric values can be entered as text by typing an apostrophe before the value (versions of Microsoft Excel earlier than 5.0) or by formatting the cells as text (Microsoft Excel version 5.0).

        -or-
    
  • Convert the lookup table and the value you are looking up to text by entering your formula into an array formula. The following is an example that assumes the value to be looked up is located in cell B1:

          =VLOOKUP(TEXT(B1,"@"),TEXT(A1:A6,"@"),1)
    

       NOTE: The above formula must be entered as an array formula. To enter a    
       formula as an array formula in Microsoft Excel for Windows, press 
       CTRL+SHIFT+ENTER. In Microsoft Excel for the Macintosh, press 
       COMMAND+RETURN.
    
    

REFERENCES

For more information about Lookup Functions, choose the Search button in Help and type:

   Lookup Functions

For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:

   ARTICLE-ID: Q163435
   TITLE     : VBA: Programming Resources for Visual Basic for
               Applications


Additional query words: 2.00 2.01 2.10 2.20 3.00 4.00 4.00a 5.00 7.00
8.00 97 xl97 VLOOKUP LOOKUP HLOOKUP MATCH mixed
Keywords : kbcode kbprg xlformula PgmHowto
Version : WINDOWS: 4.0 ,5.0, 5.0c, 7.0, 97; MACINTOSH: 4.0, 5.0, 98
Platform : MACINTOSH WINDOWS
Issue type : kbprb
Solution Type : kbworkaround


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.