Solved: The .FIND Method ... Arrrrrgh!
I'm not sure I've ever used the FIND method successfully, but the following code is my latest unsuccessful attempt:
[VBA]Sub FindTest()
Dim TgtRng As Range
With Worksheets("Main").Range("E12:E14") '<-(A date in each cell)
Set TgtRng = .Find(Range("E13"), LookIn:=xlValues)
If TgtRng Is Nothing _
Then MsgBox "Not Found" _
Else MsgBox TgtRng.Address
End With
End Sub[/VBA]
What am I missing?? http://vbaexpress.com/forum/images/smilies/banghead.gif
My Christmas Present (One-Line Find)
Hi Sid,
Had my christmas dinner and an idea to make the Find method a simple "one-liner" for most purposes. So here's my Christmas present to you and all others who want it.
Keep the two functions 'LookFor' and 'FindDates' handy for whenever you need to use "Find". The parameters in both these functions are simple - what you're looking for, and, the range where you want to look.
The LookFor function has the most common parameters set as: LookIn:=xlValues, SearchOrder:=xlByRows, LookAt:=xlPart, MatchCase:=False
The FindDates function has the most common parameters set as: LookIn:=xlFormulas, SearchOrder:=xlByRows
There are some examples given below on how to use these two functions, but here's the functions first...
[vba]Option Explicit
Public Function LookFor(ByRef What As String, Optional LookInRange As Range) As String
If LookInRange Is Nothing Then Set LookInRange = ActiveSheet.Cells
Dim Target As Range, FirstAddress As String
With LookInRange
Set Target = .Find(What, LookIn:=xlValues, SearchOrder:=xlByRows, _
LookAt:=xlPart, MatchCase:=False)
If Not Target Is Nothing Then
FirstAddress = Target.Address '<< bookmark the start-point of the search
Do
If Target Is Nothing Or Target.Address = FirstAddress Then
LookFor = Target.Address & LookFor
Else
LookFor = Target.Address & ", " & LookFor
End If
Set Target = .FindNext(Target)
Loop Until Target Is Nothing Or Target.Address = FirstAddress
End If
End With
End Function
Public Function FindDates(ByRef FindDate As Date, Optional LookInRange As Range) As String
If LookInRange Is Nothing Then Set LookInRange = ActiveSheet.Cells
Dim Target As Range, FirstAddress As String
With LookInRange
Set Target = .Find(FindDate, LookIn:=xlFormulas, SearchOrder:=xlByRows)
If Not Target Is Nothing Then
FirstAddress = Target.Address '<< bookmark the start-point of the search
Do
If Target Is Nothing Or Target.Address = FirstAddress Then
FindDates = Target.Address & FindDates
Else
FindDates = Target.Address & ", " & FindDates
End If
Set Target = .FindNext(Target)
Loop Until Target Is Nothing Or Target.Address = FirstAddress
End If
End With
End Function[/vba]Here's some 'LookFor' demos
[vba]Sub LookFor_Demo1()
Dim MyValue As String
MyValue = InputBox("Find What?", "Looking For")
If MyValue = Empty Or MyValue = "vbCancel" Then Exit Sub
On Error GoTo NothingFound '< can't select nothing
Range(LookFor(MyValue)).Select
Exit Sub
NothingFound:
MsgBox "There are no entries for " & MyValue
End Sub
Sub LookFor_Demo2()
Dim MyValue As String
MyValue = InputBox("Find What?", "Looking For")
If MyValue = Empty Or MyValue = "vbCancel" Then Exit Sub
If LookFor(MyValue) = Empty Then
MsgBox "There are no entries for " & MyValue
Else
MsgBox MyValue & "'s found at " & LookFor(MyValue)
End If
End Sub
Sub LookFor_Demo3()
Dim MyValue As String
MyValue = InputBox("Find What?", "Looking For")
If MyValue = Empty Or MyValue = "vbCancel" Then Exit Sub
On Error GoTo NothingFound '< can't colour nothing
Range(LookFor(MyValue)).Interior.ColorIndex = 4
Exit Sub
NothingFound:
MsgBox "There are no entries for " & MyValue
End Sub[/vba]Here's a 'FindDates' demo
[vba]'do what you want below, the example given is just to find and select...
'you could use Range(FindDates(MyDate, [A1:F50])).Interior.ColorIndex = 4
'or maybe MsgBox FindDates(MyDate, Range("A1:E50")) ... etc.
Sub FindDates_Demo()
Dim MyDate As Date
MyDate = Application.InputBox("What date?", "Date", , , , , , 1)
If MyDate = Empty Or MyDate = vbCancel Then Exit Sub
On Error GoTo NothingFound '< can't select nothing
Range(FindDates(MyDate)).Select
Exit Sub
NothingFound:
MsgBox "There are no entries for " & MyDate
End Sub[/vba]Note that as the repeated property calls (such as Interior.ColorIndex = 4) have all been removed from the Do Loop and placed as a single action in the calling procedure this (without testing) SHOULD be faster than the normal usage for a "Find and do some things" in a procedure.
Merry Christmas!
John :)