find and highlight exact numerical value

katana_flyer

New Member
Joined
Feb 19, 2020
Messages
17
Office Version
  1. 2013
Platform
  1. Windows
Hi everyone, been looking through other posts and have found similar, just can't seem to quite get it right.
I'm trying to find all cells containing a certain number, then highlighting them.
This code that I found on another post, nearly works but the problem I'm finding is if I enter "1" as the search number, it is finding all cells with 1 and also any number containing 1, such as 12, 13,110 etc.... Can anyone offer a modification to help sort it out?

(I'm a beginner so it may be an obvious answer to most)

Thank you

VBA Code:
Dim fnd As String, FirstFound As String
Dim FoundCell As Range, rng As Range
Dim myRange As Range, LastCell As Range

'What value do you want to find?
  fnd = InputBox("I want to hightlight cells with a value of ...", "Highlight")
  
    'End Macro if Cancel Button is Clicked or no Text is Entered
     If fnd = vbNullString Then Exit Sub

Set myRange = ActiveSheet.UsedRange
Set LastCell = myRange.Cells(myRange.Cells.Count)
Set FoundCell = myRange.Find(what:=fnd, after:=LastCell)

'Test to see if anything was found
  If Not FoundCell Is Nothing Then
    FirstFound = FoundCell.Address
  Else
    GoTo NothingFound
  End If

Set rng = FoundCell

'Loop until cycled through all unique finds
  Do Until FoundCell Is Nothing
    'Find next cell with fnd value
      Set FoundCell = myRange.FindNext(after:=FoundCell)
    
    'Add found cell to rng range variable
      Set rng = Union(rng, FoundCell)
    
    'Test to see if cycled through to first found cell
      If FoundCell.Address = FirstFound Then Exit Do
      
  Loop

'Highlight Found cells yellow
  rng.Interior.Color = RGB(255, 255, 0)

'Report Out Message
  MsgBox rng.Cells.Count & " cell(s) were found with value of : " & fnd

Exit Sub

'Error Handler
NothingFound:
  MsgBox "No cells containing: " & fnd & " were found in this worksheet"
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
found an answer to my own question
VBA Code:
Set FoundCell = myRange.Find(what:=fnd, after:=LastCell, Lookat:=xlWhole )
 
Upvote 0
found an answer to my own question
VBA Code:
Set FoundCell = myRange.Find(what:=fnd, after:=LastCell, Lookat:=xlWhole )
But, I do wonder if there is a simple way for it to search sheet 1 and sheet 2, instead of just active sheet?

Thanks,
 
Upvote 0
Hi @katana_flyer, welcome to MrExcel.

Here another way to change the format. It only applies with values, not with formula results.

VBA Code:
Sub Macro1()
  Dim fnd As Variant
  fnd = InputBox("I want to hightlight cells with a value of ...", "Highlight")
  If fnd = vbNullString Then Exit Sub
  ActiveSheet.Cells.Find ("*")
  Application.ReplaceFormat.Clear
  Application.ReplaceFormat.Interior.Color = RGB(255, 255, 0)
  ActiveSheet.Cells.Replace fnd, fnd, xlWhole, , False, False, False, True
  Application.ReplaceFormat.Clear
End Sub
 
Upvote 0
But, I do wonder if there is a simple way for it to search sheet 1 and sheet 2, instead of just active sheet?

Maybe:
VBA Code:
Sub Macro1()
  Dim fnd As Variant
  fnd = InputBox("I want to hightlight cells with a value of ...", "Highlight")
  If fnd = vbNullString Then Exit Sub
  ActiveSheet.Cells.Find ("*")
  Application.ReplaceFormat.Clear
  Application.ReplaceFormat.Interior.Color = RGB(255, 255, 0)
  Sheets("Sheet1").Cells.Replace fnd, fnd, xlWhole, , False, False, False, True
  Sheets("Sheet2").Cells.Replace fnd, fnd, xlWhole, , False, False, False, True
  Application.ReplaceFormat.Clear
End Sub
 
Upvote 0
Maybe:
VBA Code:
Sub Macro1()
  Dim fnd As Variant
  fnd = InputBox("I want to hightlight cells with a value of ...", "Highlight")
  If fnd = vbNullString Then Exit Sub
  ActiveSheet.Cells.Find ("*")
  Application.ReplaceFormat.Clear
  Application.ReplaceFormat.Interior.Color = RGB(255, 255, 0)
  Sheets("Sheet1").Cells.Replace fnd, fnd, xlWhole, , False, False, False, True
  Sheets("Sheet2").Cells.Replace fnd, fnd, xlWhole, , False, False, False, True
  Application.ReplaceFormat.Clear
End Sub
Hi there DanteAmor, thank you very much..... worked like a charm,
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
I have one further question, would you know if possible to search for a certain number of cells with certain cell formatting. For example , after searching for and highlighting certain values, i would like it to find cases where there are 3 consecutive cells either vertically, horizontally or diagonally with that highlighting (no matter thevalue in each cell) then do......something ......probably a message box. Which I know how to do. Even if you could give me an idea of what maywork then I can try to figure it out. Thank you.
 
Upvote 0
i would like it to find cases where there are 3 consecutive cells either vertically, horizontally or diagonally with that highlighting

This is a new topic, and maybe take up the initial macro you put. Perhaps, when finding the cell with the value, search for adjacent cells and identify equal values.
Create a new thread and explain how you want the result, what would happen if there is more than 1 a case with 3 consecutive cells.
 
Upvote 0
This is a new topic, and maybe take up the initial macro you put. Perhaps, when finding the cell with the value, search for adjacent cells and identify equal values.
Create a new thread and explain how you want the result, what would happen if there is more than 1 a case with 3 consecutive cells.
Oh yes sorry. Still getting used to forum rules. Will post a new one. Thank you sincerely
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,178
Members
453,021
Latest member
Justyna P

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