Set conditional formatting with VBA

FryGirl

Well-known Member
Joined
Nov 11, 2008
Messages
1,368
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
In this code, I would like to loop through the cells (which I already have done), but how can I add in the looping of the different conditions? Fm1, then Fm2, then Fm3, etc.

The only thing that changes between the different constants is the $G5 and $H5

VBA Code:
Sub SetCF()
Dim LastRow As Long: LastRow = Cells(Rows.Count, "A").End(xlUp).Row
Dim LastColumn As Long: LastColumn = Cells(4, Columns.Count).End(xlToLeft).Column
Const Fm1$ = "=OR($G5<$F$1,$H5<$G$1)"
Const Fm2$ = "=OR($K5<$F$1,$L5<$G$1)"
Const Fm3$ = "=OR($O5<$F$1,$P5<$G$1)"
Const Fm4$ = "=OR($S5<$F$1,$T5<$G$1)"
Const Fm5$ = "=OR($W5<$F$1,$X5<$G$1)"
Const Fm6$ = "=OR($AA5<$F$1,$AB5<$G$1)"
Const Fm7$ = "=OR($AE5<$F$1,$AF5<$G$1)"
Const Fm8$ = "=Len(E5)>0"

Dim i As Long

For i = 5 To LastColumn Step 4
With Cells(5, i).Resize(62, 4)
With .FormatConditions
With .Add(Type:=xlExpression, Formula1:=Fm1)
.Borders.LineStyle = xlContinuous
.Interior.Color = RGB(244, 176, 132)
End With
End With
End With
Next i

End Sub
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
I don't have the context of your data, but reviewing an example with your conditional formats, I detect the following:

- A loop is not necessary for columns.
- Instead of constants for the formulas, we are going to use an array.

VBA Code:
Sub SetCF()
  Dim LastColumn As Long
  Dim ar As Variant, frm As Variant
 
  LastColumn = Cells(4, Columns.Count).End(xlToLeft).Column
 
  ar = Array("=OR($G5<$F$1,$H5<$G$1)", _
             "=OR($K5<$F$1,$L5<$G$1)", _
             "=OR($O5<$F$1,$P5<$G$1)", _
             "=OR($S5<$F$1,$T5<$G$1)", _
             "=OR($W5<$F$1,$X5<$G$1)", _
             "=OR($AA5<$F$1,$AB5<$G$1)", _
             "=OR($AE5<$F$1,$AF5<$G$1)", _
             "=Len(E5)>0")
 
  Cells.FormatConditions.Delete
  For Each frm In ar
    With Cells(5, 5).Resize(62, LastColumn)
      With .FormatConditions
        With .Add(Type:=xlExpression, Formula1:=frm)
          .Borders.LineStyle = xlContinuous
          .Interior.Color = RGB(244, 176, 132)
        End With
      End With
    End With
  Next
End Sub

Try and comment
😇
 
Upvote 1
Solution

Forum statistics

Threads
1,223,887
Messages
6,175,199
Members
452,617
Latest member
Narendra Babu D

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