Home |
Search |
Today's Posts |
|
#1
![]()
Posted to microsoft.public.excel.newusers
|
|||
|
|||
![]()
I am starting two dates in my example. The first is 6/20/02 and the
second is 1/15/2006. I need to calculate in separate columns for years 2001 through 2006 the number of day in this year that are between these two dates. For example, in 2001, the answer is -, in 2002, the answer is 194, and in years 2003 through 2005, the answer is 365, and finally in 2006, the answer is 15 days. The formula below almost works, but 2001 it came up with a negative number. =MIN(IF(DATE(O1,12,31)<$K$2,0,MIN((DATE(O1,12,31)-$K$2), 365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12,31)-$K$2),365),G2- DATE(O1,1,1)+1)) Surely there is a function to handle this sort of thing. Thanks, Bruce |
#2
![]()
Posted to microsoft.public.excel.newusers
|
|||
|
|||
![]()
"Revenue" wrote:
The first is 6/20/02 and the second is 1/15/2006. I need to calculate in separate columns for years 2001 through 2006 the number of day in this year that are between these two dates. First, I calculate a total of 1306 days, namely: DATE(2006,15,1) - DATE(2002,6,20) + 1 (formatted as General). If you agree with that method of counting, and if the start and end dates are in J2 and K2 respectively, and the years 2001 through 2006 as in O1:O6, then put the following formula into O1, format as General if necessary, and copy down through O6: =MAX(0, MIN(DATE(O1,12,31),$K$2) - MAX(DATE(O1,1,1),$J$2) + 1) ----- original message ----- "Revenue" wrote in message ... I am starting two dates in my example. The first is 6/20/02 and the second is 1/15/2006. I need to calculate in separate columns for years 2001 through 2006 the number of day in this year that are between these two dates. For example, in 2001, the answer is -, in 2002, the answer is 194, and in years 2003 through 2005, the answer is 365, and finally in 2006, the answer is 15 days. The formula below almost works, but 2001 it came up with a negative number. =MIN(IF(DATE(O1,12,31)<$K$2,0,MIN((DATE(O1,12,31)-$K$2), 365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12,31)-$K$2),365),G2- DATE(O1,1,1)+1)) Surely there is a function to handle this sort of thing. Thanks, Bruce |
#3
![]()
Posted to microsoft.public.excel.newusers
|
|||
|
|||
![]()
Note that 2004 was a leap year, thus 366 days.
J2: Smaller/Start Date K2: Larger/Finish Date O2:U2 contain the numbers 2001 thought 2008 In O3: =IF(OR(YEAR($J$2)O2,YEAR($K$2)<O2),0,MIN($K$2,DAT E(P2,,))-MAX($J$2,DATE(O2,,))) -- Best Regards, Luke M "Revenue" wrote in message ... I am starting two dates in my example. The first is 6/20/02 and the second is 1/15/2006. I need to calculate in separate columns for years 2001 through 2006 the number of day in this year that are between these two dates. For example, in 2001, the answer is -, in 2002, the answer is 194, and in years 2003 through 2005, the answer is 365, and finally in 2006, the answer is 15 days. The formula below almost works, but 2001 it came up with a negative number. =MIN(IF(DATE(O1,12,31)<$K$2,0,MIN((DATE(O1,12,31)-$K$2), 365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12,31)-$K$2),365),G2- DATE(O1,1,1)+1)) Surely there is a function to handle this sort of thing. Thanks, Bruce |
#4
![]()
Posted to microsoft.public.excel.newusers
|
|||
|
|||
![]()
Thanks, I got your example formula to work.
On Mar 29, 2:40*pm, "Luke M" wrote: Note that 2004 was a leap year, thus 366 days. J2: Smaller/Start Date K2: Larger/Finish Date O2:U2 contain the numbers 2001 thought 2008 In O3: =IF(OR(YEAR($J$2)O2,YEAR($K$2)<O2),0,MIN($K$2,DAT E(P2,,))-MAX($J$2,DATE(O2*,,))) -- Best Regards, Luke M"Revenue" wrote in message ... I am starting two dates in my example. The first is 6/20/02 and the second is 1/15/2006. I need to calculate in separate columns for years 2001 through 2006 the number of day in this year that are between these two dates. For example, in 2001, the answer is -, in 2002, the answer is 194, and in years 2003 through 2005, the answer is 365, and finally in 2006, the answer is 15 days. The formula below almost works, but 2001 it came up with a negative number. =MIN(IF(DATE(O1,12,31)<$K$2,0,MIN((DATE(O1,12,31)-$K$2), 365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12,31)-$K$2),365),G2- DATE(O1,1,1)+1)) Surely there is a function to handle this sort of thing. Thanks, Bruce- Hide quoted text - - Show quoted text - |
#5
![]()
Posted to microsoft.public.excel.newusers
|
|||
|
|||
![]()
Well, I was getting a negative number for 2006 until I changed the "G2"
reference in your formula to J2, then I got 15 days for 2006. If we can assume that if the formula results in a negative number, then it's outside of your timeframe, you can write the formula like this: =IF(MIN(IF(DATE(O1,12,31)<$K$2,0,MIN((DATE(O1,12,3 1)-$K$2),365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12 ,31)-$K$2),365),$J$2-DATE(O1,1,1)+1))<0,0,MIN(IF(DATE(O1,12,31)<$K$2,0, MIN((DATE(O1,12,31)-$K$2),365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12 ,31)-$K$2),365),$J$2-DATE(O1,1,1)+1))) That just evaluates the formula, and if it evaluates to <0, then a 0 is displayed, otherwise it gets evaluated again and the non-zero result is displayed. "Revenue" wrote: I am starting two dates in my example. The first is 6/20/02 and the second is 1/15/2006. I need to calculate in separate columns for years 2001 through 2006 the number of day in this year that are between these two dates. For example, in 2001, the answer is -, in 2002, the answer is 194, and in years 2003 through 2005, the answer is 365, and finally in 2006, the answer is 15 days. The formula below almost works, but 2001 it came up with a negative number. =MIN(IF(DATE(O1,12,31)<$K$2,0,MIN((DATE(O1,12,31)-$K$2), 365)),IF(DATE(O1,12,31)<$J$2,MIN((DATE(O1,12,31)-$K$2),365),G2- DATE(O1,1,1)+1)) Surely there is a function to handle this sort of thing. Thanks, Bruce . |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
convert number of days into years/months | Excel Discussion (Misc queries) | |||
count number of dates falling in the next seven days | Excel Worksheet Functions | |||
Formula for number of years in 750 days | Excel Discussion (Misc queries) | |||
how do i convert a number of days to years, months & days? | Excel Discussion (Misc queries) | |||
how do I convert a number to number of years, months and days | Excel Worksheet Functions |