Logicwurks Home Page

Links To Excel Code Examples

Tracing VBA Statements
Range/Wkb/Wks Variables
Add Grand Totals Using Ranges
Using Range Offset Property
Using Range Find Method
ConvertCellAddressToRange
Set Conditional Formatting
Union Of Ranges
Parse Range Strings
Delete Duplicate Rows
Delete Rows And Columns
Worksheet Variables
TypeName And TypeOf
Loop Through Worksheets
Loop Through Open Workbooks
Form Button Magic
Command Button Magic
Add Worksheets Dynamically
ImportExternalWorksheets
Find Last Row Or Column
Copy And Paste Special
Copy To Specific Cell Types
Range Copy With Filter
ExcelFileOpenSaveClose
ExcelFileOpenSaveCSV
Open An Excel File
Open An Excel File w/Params
Open An Excel File On Web
Save A Workbook
Save A Workbook Using mso
Clone A Workbook
Test If WEB URL Exists
Parse Using Split Command
Using Classes in Excel
TypeStatementStructures
Color Management
Convert Cell Color To RGB
Sort Methods 2003 - 2010
Sort Alpha/Numeric In ASCII
Search Using Match Function
Search Using Vlookup Function
Search Using Xlookup Function
Using Find Instead of Vlookup
Remove String Non-Printables
Auto_Open And Auto_Close
Initialize Form At Open
Edit Numerics In UserForm
Load Combo And List Boxes
Floating Sheet Combo Boxes
Advanced User Form Coding
Excel Events
Worksheet Change Events
Binary Search Of Array
Typecast Constants
Excel Error Handling
Handling Optional Parameters
Data Validation Drop Downs
Insert Data Validation Sub
Read A Text File w/Handle
Write A Text File w/Handle
Read a Binary File w/Handle
Update a Binary File w/Handle
Binary File Copy and Update
Read A Text Fiile w/Script
Text File Processing Examples
Test For Exists Or Open
Splash Screen
Dynamically Load Formulas
PaymentStreamsByDate
Date Examples
Date Find Same Days
Convert Month To Number
Initialize Arrays
Load Arrays Using Evaluate
ChartsAndGraphsVBA
Redim An Array
Reassign Button Action
Timer Functions
Legacy Calendar Control
Excel 2010 Date Picker
Date Picker Alternative
Generate Multiple Worksheets
Read Access Data Into Excel
Send Outlook Email w/Attach
Copy AutoFilters To Sheets
Export A Text File
Get Windows User Name
VBA Format Statement
Manipulate Files via VBA
Dynamically Load Images
Loop Through Worksheet Objects
Loop Through Form Objects
Loop Through Files with DIR
Active-X Checkboxes
Add Forms Checkboxes Dynam
Paste Pictures Into Excel
Copy Pictures Sheet To Sheet
Copy Pictures Sheet To Sheet
Create Forms Buttons With VBA
Extract Filename From Path
Convert R1C1 Format to A1
Special Cells Property
Insert Cell Comments

Links To Access Code Examples

DAO Versus ADODB
SearchVBACodeStrings
Interface Excel With Access
Create Form Manually
Create Recordset With AddNew
Multi-Select List Boxes
Update Field(s) In A Recordset
Update Excel Pivot From Access
Import A Tab Delimited File
Export Excel FileDialog
Create Excel Within Access
Open Excel Within Access
Open Excel OBJ From Access
Format Excel From Access
Control Excel via Access VBA
On Error Best Practices
Import Tab Delim w/WinAPI
Initialize Global Variables
Using TempVars For Globals
Access Error Handling
Loop Through Form Controls
Insert A Calendar Control
Create A Filtered Recordset
Populate Combo Boxes
Bookmarks And Forms
Combo Box Multiple Sources
Passing Form Objects
Create VBA SQL Statements
Create Dynamic Queries
Display File Images On A Form
Manipulate Files via VBA
Manipulate Files via Scripting
Number Subform Records
Reference Subform Objects
Parse Delimited Fields
Parameterized Queries (VBA)
Manipulating QueryDefs In VBA
FindFirst On Combined Keys
Dlookup Command
Dlookup In Form Datasheet
Execute SQL Delete Records
Commit Form To Table
Report With No Data
Reference Form Objects
DSNLess Connections To MySQL
Print Active Form Record
Count Records in Linked Tables
Delete Empty Tables
Open Linked SQL Tables

 

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