Make Cell change colour automatically

Lolarsso

New Member
Joined
Jul 7, 2022
Messages
1
Office Version
  1. 365
Platform
  1. Windows
Hello
I have a time consuming problem. I make a lot of risk analyzes and depending on the probability and the consequence the risk is marked with Green, Yellow or Red.
Now I change the colour manually but it would save a lot of time if the cell changed colour depending on the values in the previous collumns.

I thought that i could add a rule for the collumn but one value can have different colours.
If the Consequence (K) is 5 the colour will always be Red.
If the value is 10 or higher the colour is Red.
(See the picture)

Is there a way to make the cells automatic?
 

Attachments

  • Excel Help.png
    Excel Help.png
    26.7 KB · Views: 9

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Book1
ABCD
1ProbConqRiskaut Color
2111
3122
4133
5144
6155
7112
8124
9236
10248
112510
12313
13326
14339
153412
164515
17414
18438
195311
205416
215520
Sheet1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
D2:D21Expression=OR($B2=5,$C2>=10)textNO
D2:D21Expression=AND($A2<=2,$B2<=2)textNO
D2:D21Expression=OR($A2>=3,$B2<=4)textNO
 
Upvote 0
I took a code index/match/match option:

Book1
ABCDEFGHIJKLMNOPQ
1ProbabilityConsequencesRiskManualAuto
211Consequence
311Probability12345
412VH563333
513H466333< colour index numbers
615M366633
714S244663
821VS144663
921
1021
1121
1222
1323
1425
1534
1631
1731
1831
1931
2032
2133
2245
2344
2441
2541
2651
2751
2852
Sheet1


Set up the sheet as above then run the below code:
VBA Code:
Sub test()
    Dim rng As Range, rCell As Range
    Dim Prob As Integer
    Dim Con As Integer
    Dim ci As Integer
    
    Set rng = Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row)

    For Each rCell In rng.Cells
        Prob = rCell.Value
        Con = rCell.Offset(, 1).Value
        With Application
            ci = .Index(Range("I4:M9"), .Match(Prob, Range("H4:H9"), 0), .Match(Con, Range("I3:M3"), 0))
        End With
        rCell.Offset(, 4).Interior.ColorIndex = ci
    Next rCell
End Sub
 
Upvote 0
oops had to tweak it a small bit and simplify a bit
1657193873735.png

Book1
D
2
Sheet1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
D2:D26Expression=AND($A2<=2,$B2<=2)textNO
D2:D26Expression=OR($B2=5,$C2>=10)textNO
D2:D26Expression=$A2+$B2>=7textNO
D2:D26Expression=OR($A2+$B2<7)textNO
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,219
Members
452,620
Latest member
dsubash

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