[mso] Re: Calculating less than 24 hours of life when crossing midnight?

  • From: "Tyto Alba" <tyto2820@xxxxxxxxxxx>
  • To: "Mso@Freelists. Org" <mso@xxxxxxxxxxxxx>
  • Date: Thu, 18 Aug 2005 16:18:28 +0100

Robert,

Having looked at this again, I think there is a fault in the IF statement.
It SHOULD check the surd parts of the two dates as follows (using my cell
references):

        IF((B2-INT(B2))<(A2-INT(A2)), <show DAYS - 1>, <show DAYS>) ... that is,
replace (B2-A2)<1 with (B2-INT(B2))<(A2-INT(A2)) in the expression.

        where DAYS means the DATEDIF with the "MD" parameter

Andrew

-----Original Message-----
From: Tyto Alba [mailto:tyto2820@xxxxxxxxxxx]
Sent: 18 August 2005 13:13
To: mso@xxxxxxxxxxxxx
Subject: RE: [mso] Calculating less than 24 hours of life when crossing
midnight?


Robert,

Copied from my test sheet - change my A2 to J5 and my B2 to J6:

Try the following:
=TEXT(DATEDIF(A2,B2,"Y"),"0000")&"-"&TEXT(DATEDIF(A2,B2,"YM"),"00")&"-"&TEXT
((IF((B2-A2)<1,(DATEDIF(A2,B2,"MD")-1),DATEDIF(A2,B2,"MD"))),"00")&"
"&TEXT(B2-A2,"hh:mm")

(This gives a format of '0000-00-00 6:44' for your calculation.  The IF
function - if you can see it! - is necessary to cope with the time of day
being less in J6 than in J5)

or: =DATEDIF(A2,B2,"Y")&"yrs, "&DATEDIF(A2,B2,"YM")&"mths,
"&(IF((B2-A2)<1,(DATEDIF(A2,B2,"MD")-1),DATEDIF(A2,B2,"MD")))&"dys,
"&TEXT(B2-A2,"hh:mm")

(just a rearrangement to give "0yrs, 0mths, 0dys 6:44"

An expansion of the final TEXT expression would, I think, give you the
format you quoted as the last of the two.

Andrew

-----Original Message-----
From: mso-bounce@xxxxxxxxxxxxx [mailto:mso-bounce@xxxxxxxxxxxxx]On Behalf Of
Robert Carneal
Sent: 18 August 2005 11:30
To: mso@xxxxxxxxxxxxx
Subject: [mso] Calculating less than 24 hours of life when crossing
midnight?


Objective: How long did this person live?
If I format as yyyy-mm-dd HH:MM, and enter 1955-10-25 19:23 in J5, and enter
1955-10-26 02:07 in J6.

Entering =J6-J5 in cell J7, yields 1900-01-00 06:44. I know and understand
that "1900" is zero in this case, but does anyone have a suggestion how work
the formula so that the answer above would read:
"0000-00-00 06:44"
-or-
0yrs 0mths 0 dys 6hrs 44 mins
????

The last two formats would be easier for non-computer literate people to
understand. I prefer the YYYY-MM-DD HH:MM format if possible. It will be
faster for students to enter.

Thank you everyone.

Robert



                
___________________________________________________________ 
To help you stay safe and secure online, we've developed the all new Yahoo! 
Security Centre. http://uk.security.yahoo.com
*************************************************************
You are receiving this mail because you subscribed to mso@xxxxxxxxxxxxx or 
MicrosoftOffice@xxxxxxxxxxxxxxxx

To send mail to the group, simply address it to mso@xxxxxxxxxxxxx

To Unsubscribe from this group, send an email to 
mso-request@xxxxxxxxxxxxx with the word "unsubscribe" (without the quotes) in 
the subject line.

Or, visit the group's homepage and use the dropdown menu.  This will also allow 
you to change your email settings to digest or vacation (no mail).
//www.freelists.org/webpage/mso

To be able to use the files section for sharing files with the group, send a 
request to mso-moderators@xxxxxxxxxxxxx and you will be sent an invitation with 
instructions.  Once you are a member of the files group, you can go here to 
upload/download files:
http://www.smartgroups.com/vault/msofiles
*************************************************************

Other related posts: