Using The Match Function To Look Up Values
For the most advanced book covering the Match function and how to use it to speed even your most demanding applications, Rich's latest book is available through Amazon.com. It includes a bonus application with code and examples you can copy for your own development efforts.
Power-Up Using Excel VBA Sorts and Searches
The Match Function provides flexible features and speed that make it the desired method of looking up values for codes. Suppose you import a worksheet that has only employee numbers, and you want to include the employee name in the report. You can create another worksheet to work as a translation table that contains both the employee number and the employee name.
The match function returns the position of the value in the translation table. So, for example, lets say that your employee translation table starts in row 5 and goes to row 11. If you find a match on the first employee, it will return "1" as the position, not "5". In other words, it returns the position relative to the searched range, not the worksheet. For this reason, you need to add the offset to arrive at the position of the matching entry relative to the worksheet. In this example, you would add 4 to the matching position.
A parameter of "1" in the match function acts in the following manner: The Match function will find the largest value that is less than or equal to your requested value. You should be sure to sort your array in ascending order. Using a parameter value of "1" provides the fastest search because the array is sorted, but since it does not guarantee an exact match, you must check to see if the search value matches the found value, and the code below illustrates.
This simplified example shows how the function works, but in an actual application, it is a good idea to take these steps:
(1) Either sort or sequence check the translation table
(2) If the searched column has both numbers and text, be sure to convert numbers to text and resort
(3) Count the rows of the translation table so that the length can be dynamic as new codes are added by the user
Program Code
Option Explicit Public Sub FindMatching() ' ******************************************************** ' Use The Match Function To Look Up An Employee Name ' From A Table Of Employee Numbers and Names ' ******************************************************** Dim shtEmployeeData As Worksheet Dim shtEmployeeTable As Worksheet Dim strEmployeeNumber As String Dim strEmployeeName As String Dim rngEmployeeNumbers As Range Dim rngSearchTable As Range Dim C As Range Dim varMatchPosition As Variant Set shtEmployeeData = Sheets("Sheet1") Set shtEmployeeTable = Sheets("Sheet2") ' ************************************************************ ' For This Example, Let's Assume: ' (1) rngEmployeeNumbers Contains A Range Of Employee Numbers ' (2) rngSearchTable Contains The Translation Table From ' Employee Number to Employee Name Sorted By Employee ' Number in ASCII Order ' ************************************************************ ' ******************************************************** ' B3:B14 Contain The Employee Numbers We Want To Translate ' ******************************************************** Set rngEmployeeNumbers = Range(shtEmployeeData.Range("B3"), shtEmployeeData.Range("B14")) ' ******************************************************** ' E5:E11 Contain The Translation Table Employee Numbers ' In Ascending Sequence, And F5:F11 Contain ' The Corresponding Employee Name ' ******************************************************** Set rngSearchTable = Range(shtEmployeeTable.Range("E5"), shtEmployeeTable.Range("E11")) ' ******************************************************** ' Since varMatchPosition Points To The Position In The ' Search Range, If The Range Does Not Start In Row 1, Then ' Add The Number Of Rows Above The Search Range To Find ' The Actual Row Number - In This Case 4 Rows ' ******************************************************** On Error Resume Next For Each C In rngEmployeeNumbers strEmployeeNumber = C.Value varMatchPosition = Application.WorksheetFunction.Match(strEmployeeNumber, rngSearchTable, 1) If Err.Number = 1004 Or Err.Number = 438 Then Err.Clear strEmployeeName = "Not Found" ElseIf strEmployeeNumber = shtEmployeeTable.Cells(varMatchPosition + 4, 5).Value Then strEmployeeName = shtEmployeeTable.Cells(varMatchPosition + 4, 6).Value Else strEmployeeName = "Not Found" End If ' ******************************************************** ' Add The Employee Name Next To The Employee Number ' ******************************************************** C.Offset(0, 1).Value = strEmployeeName Next C On Error GoTo 0 End Sub Example 2: Look at EVERY entry... The table to be searched does not need to be in order Public Sub FindMatching() ' ******************************************************** ' Look Up Body Code From Style/Color ' ******************************************************** Dim shtSHP300 As Worksheet Dim shtStyleColor As Worksheet Dim strStyleColor As String Dim strBodyCode As String Dim rngSHP300 As Range Dim rngStyleColor As Range Dim C As Range Dim varMatchPosition As Variant Set shtSHP300 = Sheets("SHP300") Set shtStyleColor = Sheets("StyleColor") Set rngSHP300 = Range(shtSHP300.Cells(2, 49), shtSHP300.Cells(4606, 49)) Set rngStyleColor = Range(shtStyleColor.Cells(2, 1), shtStyleColor.Cells(2239, 1)) On Error Resume Next For Each C In rngSHP300 strStyleColor = C.Value varMatchPosition = Application.WorksheetFunction.Match(strStyleColor, rngStyleColor, 0) If Err.Number = 1004 Or Err.Number = 438 Then Err.Clear shtSHP300.Cells(C.Row, 50) = "" Else: shtSHP300.Cells(C.Row, 50) = shtStyleColor.Cells(varMatchPosition + 1, 4).Value End If Next C On Error GoTo 0 End Sub