Conditional Formatting for 2 Values

Jenawade

Board Regular
Joined
Apr 8, 2002
Messages
231
I've tried to work this out myself via a search of old posts with no luck. I have column F filled with dates and column G filled with either Pending or Complete. I need them both (preferred), or at least the dates in column F, to turn yellow if the date in column F has passed AND column G in that row says 'Pending'. So, if I have:

F (Date) G (Status)
2) 12/5/03 Complete
3) 2/12/04 Complete
4) 1/19/04 Pending
5) 3/17/04 Pending
6) 2/30/04 Pending
7) 1/25/04 Pending
8) 1/15/04 Complete

I need rows 4 & 7, column F (hopefully G as well) to change to yellow.

Any help would be very much appreciated!
Jen
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,209
Select F2:G8.
Activate Format|Conditional Formatting.
Choose Formula is for Condition 1.
Enter the following in the white box:

=N($F2)*($F2 < TODAY())*($G2="Pending")

Activate the Format button.
Choose yellow from the Patterns tab.
Click OK, OK.
 

Greg Truby

MrExcel MVP
Joined
Jun 19, 2002
Messages
10,022
Looks like Aladin just beat me to the punch - and as usual he thought of something I didn't which was to check to see if there was a number there to begin with...

So just one light-hearted question: #6? 2/30/04???
 

Positive Parrot

New Member
Joined
Jan 16, 2004
Messages
35
Jen,

How about something like

Code:
Sub Yellow

Range("F2").Select
Do Until ActiveCell.Value = ""
If DateValue(ActiveCell.Value) < Now And ActiveCell.Offset(0, 1).Value = "Pending" Then
For i = 0 To 1
ActiveCell.Offset(0, i).Activate
With Selection.Interior
       .ColorIndex = 6
End With
Next i
ActiveCell.Offset(0, -1).Activate
End If
ActiveCell.Offset(1, 0).Activate
Loop

End Sub

Or if you set it up under the Worksheet_Activate event macro it should run whenever you select the sheet

Regards,

PP
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,209
Greg Truby said:
...So just one light-hearted question: #6? 2/30/04???

Alas, we don't have a worksheet function comparable to IsDate in VBA for checking the date values. What I included is rather a weak test -- though it excludes empty cells effectively. However, there is a convoluted way using CELL to test dates. I posted a few times such a test. Amazingly, it never captured the attention.
 

Jenawade

Board Regular
Joined
Apr 8, 2002
Messages
231
Greg Truby said:
So just one light-hearted question: #6? 2/30/04???

:oops: You wanna know the really bad part? I had to look at it a few seconds before I even realized what you meant! I guess I'm just living in my own little world here where we have a 2/30!

Thanks a ton - You guys are the greatest - God I love this site!
~Jen
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,152,101
Messages
5,768,101
Members
425,453
Latest member
bince

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
Top