Conditional format VBA based on other cells

JSINISCALCHI

New Member
Joined
Jul 17, 2007
Messages
5
I am trying to convert the following macro to a Worksheet (section change) format, but cannot figure out how to have the cells B87:M150 change based upon the text (red, green, white, amber, na) in O87:o150.


Sub ordinate()
Dim r As Range
For Each r In Range("o87:o150")

If r.Value = "RED" Then
r.EntireRow.Interior.ColorIndex = 3

ElseIf r.Value = "AMBER" Then
r.EntireRow.Interior.ColorIndex = 44

ElseIf r.Value = "WHITE" Then
r.EntireRow.Interior.ColorIndex = 2

ElseIf r.Value = "GREEN" Then
r.EntireRow.Interior.ColorIndex = 4

ElseIf r.Value = "NONE" Then
r.EntireRow.Interior.ColorIndex = 2

ElseIf r.Value = "NA" Then
r.EntireRow.Interior.ColorIndex = 15
End If
Next

Range("N86:IV132").Interior.ColorIndex = 2
Range("A86:A132").Interior.ColorIndex = 2
End Sub
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
Something like this:
Code:
Option Compare Text
Option Explicit
Private Sub Worksheet_Change(ByVal Target As Range)

Dim mycolor As Long
If Intersect(Range("O87:O150"), Target) Is Nothing Or Target.Count > 1 Then Exit Sub
Select Case Target.Value
    Case "Red"
        mycolor = 3
    Case "Amber"
        mycolor = 44
    Case "White"
        mycolor = 2
    Case "Green"
        mycolor = 4
    Case "None"
        mycolor = 2
    Case "NA"
        mycolor = 15
End Select
Range(Cells(Target.Row, "B"), Cells(Target.Row, "M")).Interior.ColorIndex = mycolor

End Sub
Note, this will only change your rows as you make changes to the O column.
 
Upvote 0
Works grest, except for formulas

Thanks,

The code works great when manually changing colors (typing the color into column O). I have the colors populate the cells based ona formula elsewhere in the spreadsheet and this code does not seem to update when the colors change.
 
Upvote 0
There are 2 ways this can be handled.... you can use a calculate event instead of change event or you can continue using the change event and change the ranges it is looking at to fit the ranges that if it is changed then the calculation will change.... right now the code will only make adjustments when the user changes O89 to O150.
 
Upvote 0
fix

Is the fix to change the worksheet sub to

Private Sub Worksheet_Change(ByVal Target As Excel. Range)?

I did this and it did not work.
 
Upvote 0
What columns will change to force the O column changes?

Or you can set it up as a calculate event which will require some very different coding but is doable.
 
Upvote 0
index cells

Thanks again for the help!

The index cells (initial calculation of color type based on conditional if statemenets) are in L7:L52. (I changed the intersect range to a smaller number of cells, O87:O132).
 
Upvote 0
index cells

Thanks again for the help!

The index cells (initial calculation of color type based on conditional if statemenets) are in L7:L52. (I changed the intersect range to a smaller number of cells, O87:O132).
 
Upvote 0
Try replacing what I gave you before with something like this:

Code:
Option Compare Text
Option Explicit
Private Sub Worksheet_Calculate()

Dim mycolor As Long, Ce As Variant
For Each Ce In Range("O87:O132")
    Select Case Ce.Value
        Case "Red"
            mycolor = 3
        Case "Amber"
            mycolor = 44
        Case "White"
            mycolor = 2
        Case "Green"
            mycolor = 4
        Case "None"
            mycolor = 2
        Case "NA"
            mycolor = 15
        Case Else
            mycolor = 0
    End Select
    Range(Cells(Ce.Row, "B"), Cells(Ce.Row, "M")).Interior.ColorIndex = mycolor
Next Ce

End Sub
 
Upvote 0

Forum statistics

Threads
1,224,808
Messages
6,181,073
Members
453,020
Latest member
mattg2448

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