Performing a Lookup with Unsorted Data in ExcelID: Q77114 
  | 
In Microsoft Excel, the VLOOKUP function searches the leftmost column of an
array for a particular value and returns the corresponding value from a
cell in another column, indicated by the col_index_num.
VLOOKUP requires that the first column of the lookup table is sorted in
ascending order. The following information describes different formulas
that you can use to return the same information returned by VLOOKUP
without requiring that the first column of the table be sorted.
   =INDEX(Table_Array,MATCH(Lookup_Value,Lookup_Array,0),Col_Index_Num)
where:
   Table_Array    = The entire lookup table
   Lookup_Value   = the value to be found in the first column of
                    "table_array"
   Lookup_Array   = the range of cells containing possible
                    lookup values
   Col_Index_Num  = the column number in "table_array" for which
                    the matching value should be returned 
   =OFFSET("top_cell",MATCH("lookup_value","lookup_array",0),"offset_col") 
   A1: Name        B1: Dept        C1: Age
   A2: Henry       B2: 501         C2: 28
   A3: Stan        B3: 201         C3: 19
   A4: Mary        B4: 101         C4: 22
   A5: Larry       B5: 301         C5: 29 
   =OFFSET(A1,MATCH("Mary",A2:A5,0),2) 
"Function Reference," version 4.0, pages 267-268, 299-300
"Function Reference," version 3.0, pages 148-149, 163-164
"Functions and Macros," version 2.1, pages 78, 320
Additional query words: 2.00 2.01 2.10 2.20 2.21 3.00 4.00 hlookup exact
Keywords          : kbhowto xlformulas 
Version           : 
Platform          : MACINTOSH WINDOWS 
Issue type        : kbinfo 
Last Reviewed: March 23, 1999