IF AND Date formulas

Mink

New Member
Joined
Aug 4, 2005
Messages
13
Date

18/12/2001

Formula
=IF(AND(D5<31/12/2001,D5>1/12/2001),D5,0)

I want this to return either the date (18/12/2001) or O if the date falls outside the parameters above. However the answer that is returned is 0-Jan-1900.

Hope someone can help
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
Mink

Not sure if your formula is always returning 0-Jan-1900 or only when it should be returning 0.

However, try these couple of things:
1. Put your 1/12/2001 and 31/12/2001 in cells (I have used D1 and D2)
2. Change the formula (I have it in D3 which is formatted as a date) to:
Code:
=IF(AND(D5<D2,D5>D1),D5,"0")
See if that helps.
Mr Excel.xls
ABCDE
1Start01/12/2001
2End31/12/2001
3Result0
4
5Given Date12/11/2001
6
Date Formula
 
Upvote 0
Thanks for the reply Peter. Its returning 0-Jan-1900 for everything and I think that using my formula it should be returning the 18/12/2001 and cant seem to see why not
 
Upvote 0
Try =IF(AND(D5<37256,D5>37226),D5,0)

(or =(IF(AND(D5<37257,D5>37225),D5,0) if you mean to include the start and end of the month.)

D5>01/01/2005 means D5>1 divided by 1 divided by 2005, which it isn't normally if it contains a date.

Excel stores dates as integer numbers, starting from 0 (1Jan1900). Understanding that makes working with Excel dates a lot easier. (Times are the decimal portion, so a date of 0.5 is 12 midday on 1Jan1900.)
 
Upvote 0
Rather than trying to work out the relevant date serial numbers, try this format:
Code:
=IF(AND(D5<DATEVALUE("31/12/2001"),D5>DATEVALUE("1/12/2001")),D5,"0")
 
Upvote 0
or even

=IF(AND(D5<37256,D5>37226),D5,text(0,"0")) if you want the screen to show 0 as opposed to 0-Jan-1900
 
Upvote 0
You could use this formula

=(D5< DATE(2001,12,31))*(D5 >DATE(2001,12,1))*D5

and custom format cell as

dd/mm/yyyy;;0
 
Upvote 0

Forum statistics

Threads
1,226,727
Messages
6,192,686
Members
453,746
Latest member
Bruce at Pubdarts

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