XL98: Unexpected Results with Mixed Text and Numbers in Lookup Table (200855)



The information in this article applies to:

  • Microsoft Excel 98 Macintosh Edition

This article was previously published under Q200855
For a Microsoft Excel 97 and later version of this article, see 213476.
For a Microsoft Excel 7.0 and earlier version of this article, see 113261.

SYMPTOMS

After you create a lookup table, you may experience either of the following symptoms:
  • Lookup functions on a worksheet may return the #N/A error value.

    -or-
  • Lookup functions in a Microsoft Visual Basic for Applications procedure or macro may produce a "type mismatch" error.
You receive these errors even though the values in the lookup table are correctly 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 Excel looks only at the numeric values.

WORKAROUND

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. You can enter numeric values as text by formatting the cells as text.

    -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: You must enter this formula as an array formula. To enter a formula as an array formula, press COMMAND+RETURN.

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.

MORE INFORMATION

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

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to 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 requirements.
   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).

REFERENCES

For more information about Lookup Functions, follow these steps:
  1. On the Help menu, click Contents and Index. If you are using a version of the Macintosh operating system that is earlier than 8.0, click Contents and Index on the Balloon Help menu.
  2. In Microsoft Excel for the Macintosh Help, click Index, and then type the following text:

    Lookup Functions

  3. Click Show Topics. Click the About lookup and references functions topic, and then click Go To.
If you cannot find the information that you want, ask the Office Assistant.


For additional information about getting help with Visual Basic for Applications, please click the article number below to view the article in the Microsoft Knowledge Base:

163435 VBA: Programming Resources for Visual Basic for Applications


Modification Type:MinorLast Reviewed:9/12/2006
Keywords:kbdtacode KB200855