Cell color based upon cell value

M

My View

I know you can use Conditional Formatting to allocate a colour for a cell
value but you are limited to 4 alternatives (ie the default cell color and
only 3 variations in Conditional Formatting).

How can I allocate a different color for 5 different cell values?

For example:
If cell value = 1 then cell color is green
If cell value = 2 then cell color is blue
If cell value = 3 then cell color is yellow
If cell value = 4 then cell color is red
If cell value = 5 then cell color is magenta

regards

PeterH
 
S

ScottO

Does it have to be cell colour, or can you accept just setting different font colours?
Rgds,
ScottO

| I know you can use Conditional Formatting to allocate a colour for a cell
| value but you are limited to 4 alternatives (ie the default cell color and
| only 3 variations in Conditional Formatting).
|
| How can I allocate a different color for 5 different cell values?
|
| For example:
| If cell value = 1 then cell color is green
| If cell value = 2 then cell color is blue
| If cell value = 3 then cell color is yellow
| If cell value = 4 then cell color is red
| If cell value = 5 then cell color is magenta
|
| regards
|
| PeterH
|
|
 
M

Microsoft

Hi Peter,

You can do that with macros. If you want to do it with macros just let me
know. Otherwise you could try recording a macro first, and modifying the
generated code.

Shafiee.
 
M

My View

Preferably cell colors as they are more obvious when looking at a large
spreadsheet.
 
M

My View

A macro would be fine. Whatever is easiest.


Microsoft said:
Hi Peter,

You can do that with macros. If you want to do it with macros just let me
know. Otherwise you could try recording a macro first, and modifying the
generated code.

Shafiee.
 
G

Gord Dibben

View

Sheet event code can do the trick.....

Private Sub Worksheet_Change(ByVal Target As Range)
Dim Num As Long
Dim rng As Range
Dim vRngInput As Variant
Set vRngInput = Intersect(Target, Range("A:A"))
If vRngInput Is Nothing Then Exit Sub
On Error GoTo endit
Application.EnableEvents = False
For Each rng In vRngInput
'Determine the color
Select Case rng.Value
Case Is = 1: Num = 10 'green
Case Is = 2: Num = 5 'blue
Case Is = 3: Num = 6 'yellow
Case Is = 4: Num = 3 'red
Case Is = 5: Num = 7 'magenta
End Select
'Apply the color
rng.Interior.ColorIndex = Num
Next rng
endit:
Application.EnableEvents = True
End Sub


Gord Dibben Excel MVP
 
M

My View

Thanks Gordon
For a person who has very little contact with Excel macros can you tell me
how to set-up the macro.
Also I only want the macro to work on certain cell ranges eg cells B4:B20
and D4:D20 and F4:F20 etc. How will this happen with a macro?
regards
PeterH
 
G

Gord Dibben

Peter

Amended code to cover the three ranges specified. The "etc." you can add.

Private Sub Worksheet_Change(ByVal Target As Range)
Dim Num As Long
Dim rng As Range
Dim vRngInput As Variant
Set vRngInput = Intersect(Target, Range("B4:B20, D4:D20, F4:F20"))
If vRngInput Is Nothing Then Exit Sub
On Error GoTo endit
Application.EnableEvents = False
For Each rng In vRngInput
'Determine the color
Select Case rng.Value
Case Is = 1: Num = 10 'green
Case Is = 2: Num = 5 'blue
Case Is = 3: Num = 6 'yellow
Case Is = 4: Num = 3 'red
Case Is = 5: Num = 7 'magenta
End Select
'Apply the color
rng.Interior.ColorIndex = Num
Next rng
endit:
Application.EnableEvents = True
End Sub

This is worksheet event code.

Right-click on the sheet tab and "View Code".

Copy/paste the code in there. Runs whenever a change is made to one of the
cells in the ranges.


Gord
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top