How to change row color based on cell value

webmeister

New Member
Joined
Sep 13, 2006
Messages
38
I have a worksheet that, in each row, has a cell with dropdown values. In VBA, how would I change the color of the entire row based on the value contained in the cell?

Any replies and assistance will be happily recieved. Thank you in advance!!
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
What column are the dropdown lists in? What value(s) = what color?

Do you want this to happen automatically when you make a selection (if you are using Excel 97, this may be a bit more difficult), or do you want to run the macro yourself?
 
Upvote 0
Try this
Code:
Sub ChoiceColor()
Dim ChoiceItem As Integer
Dim i As Long
Dim LR As Long
LR = ActiveSheet.Range("A65536").End(xlUp).Row
For i = 2 To LR
ChoiceItem = Range("A" & i).Value
 Select Case ChoiceItem
      Case 1
         Range("a" & i).EntireRow.Interior.ColorIndex = 6
      Case 2
         Range("a" & i).EntireRow.Interior.ColorIndex = 7
      Case 3
         Range("a" & i).EntireRow.Interior.ColorIndex = 8
      Case 4
         Range("a" & i).EntireRow.Interior.ColorIndex = 9
      Case 5
         Range("a" & i).EntireRow.Interior.ColorIndex = 3
      Case 6
         Range("a" & i).EntireRow.Interior.ColorIndex = 4
      Case 7
         Range("a" & i).EntireRow.Interior.ColorIndex = 5
   End Select
Next i
End Sub
 
Upvote 0
Von Pookie,
the values are in column N in my worksheet. What are you having in mind?

texasalynn,
how would I use your suggestion if my values are alphanumeric? Also, please excuse my knowledge of Excel, but where can I find the color index values your code uses?

Thank you both so much for replying so quickly!! Looking forward to your replies!
 
Upvote 0
Why not use conditional formatting in this case.


CF- formula is - =$N1="Mike" or what ever.

etc.

Pekka
:eek: :eek:
 
Upvote 0
Pekkavee,

Thanks for replying. I would have used conditional formatting, however I have more than three values to check for. That's why I'm looking to VBA as a solution to my question.

Any VBA ideas you might care to toss my way?

Thanks again! Looking forward to hearing back from you!
 
Upvote 0
Von Pookie,
the values are in column N in my worksheet. What are you having in mind?
I was thinking of using a Worksheet_Change event. If the dropdowns are all in one column, that's perfect. Also, you need to be using Excel 2000 or later for this to work.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim clr As Variant

'if more than 1 cell is changed, do nothing
If Target.Cells.Count > 1 Then Exit Sub

'if the changed cell is not in column N, do nothing
If Intersect(Target, [N:N]) Is Nothing Then Exit Sub

'determine what to do based on the value of the changed cell
Select Case Target.Value
    Case Is = "item1" ' if this is the cell value
        clr = 3 ' use this colorindex for the row (3=red)
    
    Case Is = "item2" 'if this is the cell value
        clr = 6 'colorindex for the row (6 = yellow)
    
    'you can add as many cases as you need
    
    'if the value of the cell is something other than
    'the cases you specified above
    Case Else
        clr = xlNone 'no color (can also use -4142)
End Select

'color the row according to the case that was used
Target.EntireRow.Interior.ColorIndex = clr

End Sub

This needs to go in the worksheet module for the sheet you want to run it on. You can right-click the sheet tab in Excel and select 'View code' to go directly there if you're not sure where it should go.

Once you have the code entered, it will run whenever a change is made on the sheet, but it should only run the entire thing if the cell that was changed is in column N.

The easiest way for me, personally to figure out what the colorindex is for a certain color is to simply use the macro recorder. Turn it on, color a cell, turn it off then look at the resulting code. I find it's quicker than messing around with custom functions and whatnot :)

Edit: Fixed minor goof in code.
 
Upvote 0
texasalynn,
how would I use your suggestion if my values are alphanumeric? Also, please excuse my knowledge of Excel, but where can I find the color index values your code uses?

Change the Case 1, etc to Case XXX whatever text you are looking for. I just picked some numbers for the colors. You could do a google search and should find several sites that can tell you that, or even a search on this forum.

Also my code is looking in column A, so you will need to change to column N
 
Upvote 0
Von Pookie,

THANK YOU!! For: Your quick reply. Your explanation.

I'll give your suggestion a shot and see what comes of it.

Thanks again! Wow, that was fast!!!!!!!!!
 
Upvote 0
texasalynn,

Thanks for your response so quickly also! I'll had kinda figured that out, but it's always nice to see an explanation in print, so to speak.

I appreciate your willingness to help!

Thanks again!
 
Upvote 0

Forum statistics

Threads
1,214,414
Messages
6,119,373
Members
448,888
Latest member
Arle8907

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