Check non-contiguous ranges help with macro needed

Jak

Well-known Member
Joined
Apr 5, 2002
Messages
833
I a trying to create a macro that checks to see if there is a value in column 1 but not in columns 7, 9, 11, 13, 15, 17, 19, 21, 23, 25. If column 1 does have a value and there are no values in either 7, 9, 11, 13, 15, 17, 19, 21, 23, 25 then the cells are coloured, other wise the cells remain uncoloured.

e.g.

Cell A2 has a value and cells G2, I2, K2, M2, O2, Q2, S2, U2, W2, Y2 are blank then the cells are highlighted.

If Cell A2 has a value and lets say K2 had a value then the cells would remain uncoloured.


I have tried to put a macro together to do this but unfortunately it does not work. Any suggestions on the code or alternative code to do this would be great.


Code:
Sub ColorRowsWithMissingData()

Dim rng1 As Range
Dim rng2 As Range
Dim R As Integer

For R = 2 To 1000

Set rng1 = ActiveSheet.Range("A" & R)
   Set rng2 = ActiveSheet.Range("G" & R & ", I" & R & ", K" & R & ", M" & R & ", O" & _
                                R & ", Q" & R & ", S" & R & ", U" & R & ", W" & _
                                R & ", Y" & R)
   
 If Application.Count(rng1.Cells) = 1 And Application.Count(rng2.Cells) = 0 Then rng2.Cells.Interior.ColorIndex = 36


Next R

MsgBox "job done"

End Sub
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Hi,

you could use conditional format for this
do you want to do this by macro anyway ?

kind regards,
Erik
 
Upvote 0
in case you want to try out CF (conditional format)
select all cells to format and use this formula
Code:
=AND($A2<>"",COUNTA($G2,$I2, $K2, $M2, $O2, $Q2, $S2, $U2, $W2, $Y2)=0)
 
Upvote 0
Hello erik.van.geit

I would prefer VB solution as the code is to fit into a larger macro.

Thanks for the CF example.
 
Upvote 0
Hello erik.van.geit

Tried your line of VB code and it works perfectly.

Thanks for the help.
 
Upvote 0

Forum statistics

Threads
1,203,244
Messages
6,054,365
Members
444,718
Latest member
r0nster

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