0 votes
ago in VBA by Expert (887 points)
Hello everyone

I am searching for a way (faster approach as the original data is too large) to search for specific text ("Yasser") in column A then when found color the two cells in A & B with any color. I tried using Find but I found it somewhat slow. Is there a faster way than using Find method
By the way the text may be YASSER or yasser or YasserKhalil so it partial search.
Thanks a lot for advanced help

2 Answers

+1 vote
ago by Skilled (582 points)
edited ago by
 
Best answer

Assuming row 1 is a header row where "Yasser" is ignored and should not be colored, try this:

Option Compare Text
Sub Color_If_Filter()
    Const s As String = "Yasser*" ' or "*Yasser*"
    Range("A:A").AutoFilter 1, s, xlFilterValues, , False
    n = Range("A" & Rows.Count).End(xlUp).Row
    For Each c In Range("A2", "B" & n).SpecialCells(xlCellTypeVisible)
        c.Interior.Color = vbYellow
    Next c
    Range("A:A").AutoFilter 1, , , , False
End Sub

Here is another version that is probably faster:

Option Compare Text
Sub Color_If_Filter()
    Dim n As Long ' last visible row with data in column 1
    Const s As String = "Yasser*" ' or "*Yasser*" if necessary
    n = Cells(Rows.Count, 1).End(xlUp).Row
    With Range("A1:B" & n)
        .AutoFilter 1, s, xlFilterValues, , False
        .SpecialCells(xlCellTypeVisible).Interior.Color = vbYellow
        .AutoFilter 1, , , , False
    End With
    Range("A1:B1").Interior.Color = xlColorIndexNone ' optional
End Sub

 

ago by Expert (887 points)
That's a very elegant trick. Perfect JWoolley. Thank you very much.
ago by Skilled (582 points)
+1
I made two minor changes to the code.
ago by Skilled (582 points)
I added another version of the code that is probably faster.
ago by Expert (887 points)
Can you guide me to the changes you made so as to learn the main points?
ago by Skilled (582 points)
+1
Please review the 2nd version of the code in my 2nd answer (see above).

1. Only cells with data in column 1 are considered/filtered.

2. All filtered cells in columns 1 and 2 are colored simultaneously (no For Each ... loop).

Do you find it faster?
ago by Expert (887 points)
Yes it is faster a little bit. Thanks a lot for your efforts.
ago by Skilled (582 points)
+1
Today I fixed 3 errors in the With...End With part of the code. Somehow the leading dot (.) was stripped from each line.
+1 vote
ago by Skilled (582 points)

Try this. It assumes the search text begins with "Yasser"; otherwise, change "Yasser*" to "*Yasser*".

Option Compare Text
Sub Color_If_Like()
    For Each c In Range("A:A")
        If c.Value Like "Yasser*" Then
            c.Interior.Color = vbYellow
            c.Offset(0, 1).Interior.Color = vbYellow
        End If
    Next c
End Sub

If you know where to end the search, you can skip the remainder of column A; for example:

        If c.Value = vbNullString Then Exit For

 

ago by Expert (887 points)
Thank you very much for your great help.
ago by Expert (887 points)
In fact, I can do loops like that but the data is too too large and using such a method takes so much time.
ago by Skilled (582 points)
See my 2nd answer.

Welcome to wellsr Q&A
wellsr Q&A is the VBA and Python programming community that rewards you for learning how to code.

Getting Started
Register
VBA Cheat Sheets (On Sale Now)

Earn free prizes for asking VBA and Python questions and for answering questions asked by others in our community.

Looking for something else? Hire our professional VBA Help, instead.

What makes us different?
Our points system rewards you with a chance for free gifts based on the quality of your questions and answers. All you have to do is post and you could get rewarded, like these members:

ParserMonster $25 Amazon Gift Card
Hightree $10 Amazon Gift Card
Thales1 $10 Amazon Gift Card
runfunke $10 Amazon Gift Card
coolag $10 Amazon Gift Card
Siew Hun $10 Amazon Gift Card

So, why don't you join us? It really is an encouraging way to motivate members in our VBA and Python community.

Register

For more programming tips visit the VBA Tutorials Blog and the Python Tutorials Blog.

...