Minimum search which crashes when there are no values

simmo

New Member
Joined
Oct 28, 2002
Messages
36
Here is code which finds minimum values in certain columns, it works great,except when there are no values in some columns, can anyone suggest any modifications that would help.
Regards
Simmo

' Sub FormatMinimum()
Range("C4:C120,E4:E120,G4:G120,I4:I120,K4:K120,L4:L120").Interior.ColorIndex = 0

Dim MinRange1 As Range, MinRange2 As Range, MinRange3 As Range, MinRange4 As Range, MaxRange5 As Range, MaxRange6 As Range

Dim MinVal1 As Long, MinVal2 As Long, MinVal3 As Long, MinVal4 As Long, MaxVal5 As Long, MaxVal6 As Long

Set MinRange1 = Range("N4:N120")
Set MinRange2 = Range("O4:O120")
Set MinRange3 = Range("P4:P120")
Set MinRange4 = Range("Q4:Q120")
Set MaxRange5 = Range("K4:K120")
Set MaxRange6 = Range("L4:L120")

MinVal1 = Application.WorksheetFunction.Min(MinRange1)
MinRange1.Find(What:=MinVal1, After:=Range("N4"), LookIn:=xlValues, _
LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, _
MatchCase:=False).Offset(0, -11).Interior.ColorIndex = 44

MinVal2 = Application.WorksheetFunction.Min(MinRange2)
MinRange2.Find(What:=MinVal2, After:=Range("O4"), LookIn:=xlValues, _
LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, _
MatchCase:=False).Offset(0, -10).Interior.ColorIndex = 44

MinVal3 = Application.WorksheetFunction.Min(MinRange3)
MinRange3.Find(What:=MinVal3, After:=Range("P4"), LookIn:=xlValues, _
LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, _
MatchCase:=False).Offset(0, -9).Interior.ColorIndex = 44
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Something like this:

Code:
Dim x As Range

MinVal1 = Application.WorksheetFunction.Min(MinRange1) 
Set x = MinRange1.Find(What:=MinVal1, After:=Range("N4"), LookIn:=xlValues, _ 
LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, _ 
MatchCase:=False)
If Not x Is Nothing Then
   x.Offset(0, -11).Interior.ColorIndex = 44
End If
 
Upvote 0
Thanks for that piece of code Andrew, do i replace my "MinVal1" statement with the one you have written ? and then replace / edit MinVal2,MinVal3 and MinVal4. I dont mean to sound dumb, but I have lots to learn.
 
Upvote 0
Replace:

Code:
MinVal1 = Application.WorksheetFunction.Min(MinRange1) 
MinRange1.Find(What:=MinVal1, After:=Range("N4"), LookIn:=xlValues, _ 
LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, _ 
MatchCase:=False).Offset(0, -11).Interior.ColorIndex = 44

with

Code:
MinVal1 = Application.WorksheetFunction.Min(MinRange1) 
Set x = MinRange1.Find(What:=MinVal1, After:=Range("N4"), LookIn:=xlValues, _ 
LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, _ 
MatchCase:=False)
If Not x Is Nothing Then
   x.Offset(0, -11).Interior.ColorIndex = 44
End If

and repeat for the other two blocks, changing variable and range references as necessary.

Dim x As Range

goes in once at the top.
 
Upvote 0

Forum statistics

Threads
1,214,642
Messages
6,120,701
Members
448,980
Latest member
CarlosWin

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