Find a string in a worksheet and return the cell reference

stever99

New Member
Joined
May 12, 2010
Messages
6
Hi everyone,

I'm a bit of a VBA noob and have been scouring forums trying to piece together the code I need for the following. Hoping someone can help.

I need a function (Excel or VBA) that can check to see if a text string in an adjacent cell exists in a different worksheet in the same workbook. This different worksheet contains many thousands of values, all unique. The formula should return the value from column A of the same row that the string was found in.

I've tried cobbling together match, index and vlookup functions without success. I'm thinking using VBA will be much cleaner.

Thanks in advance for any help you can give me! :)
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Here's one way using the "Find" method.

Gary

Code:
Dim oFound As Range
Dim oLookin As Range
Dim sLookFor As String

sLookFor = "xxxyyyzzz" 'Change to suit

Set oLookin = Worksheets("Sheet2").UsedRange 'Change sheet name to suit

Set oFound = oLookin.Find(what:=sLookFor, LookIn:=xlValues, LookAt:=xlPart, MatchCase:=False)

If Not oFound Is Nothing Then
    MsgBox oLookin.Range("A" & oFound.Row).Value
End If
 
Upvote 0
That does the trick, great!

Would you be able to tell me how I make that macro look in the adjacent cell for the value to find, and then return the value from column A in the active cell instead of displaying the message box?

Again - thanks so much!
 
Upvote 0
I don't know exactly what you mean? The range variable "oFound" contains a reference to the first cell in which "sLookFor" was found, if any. You could use "Offset" to get a reference to adjacent cell(s) as needed. Instead of displaying the message box just put the value in the active cell or wherever else you need it.

Gary

Code:
Dim oFound As Range
Dim oLookin As Range

Dim sLookFor As String

sLookFor = "xxxyyyzzz"

Set oLookin = Worksheets("Sheet2").UsedRange

Set oFound = oLookin.Find(what:=sLookFor, LookIn:=xlValues, LookAt:=xlPart, MatchCase:=False)


Dim oAdjacent As Range

If Not oFound Is Nothing Then
    
    'MsgBox oLookin.Range("A" & oFound.Row).Value
    ActiveCell.Value = oLookin.Range("A" & oFound.Row).Value
    Set oAdjacent = oFound.Offset(0, 1) ' One cell to right
    
End If
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,853
Members
452,361
Latest member
d3ad3y3

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top