+ Reply to Thread
Results 1 to 15 of 15

Excel function to calculate minutes to days, hours, minutes

  1. #1
    Forum Contributor
    Join Date
    01-05-2011
    Location
    India
    MS-Off Ver
    Excel 2013
    Posts
    243

    Excel function to calculate minutes to days, hours, minutes

    I am looking for assistance with excel function to find the minutes converted to days, hours, minutes in the attached. In Column A I have the values and result in column B. Can this be populated with the help of excel function in Column C?
    Attached Files Attached Files
    Last edited by vijanand1279; 06-12-2020 at 05:53 AM.

  2. #2
    Forum Expert
    Join Date
    10-10-2016
    Location
    Sheffield
    MS-Off Ver
    365 and rarely 2016
    Posts
    3,212

    Re: Time formula

    perhaps
    =TEXT(A2/(24*60*60),"dd \d\a\y\s h \h\o\u\r\s m \m\i\n\u\t\e\s")

    reduce to days and as above

  3. #3
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Time formula

    Administrative Note:

    We would very much like to help you with your query, however the thread title does not really convey what your request is about. Tell us what you are trying to do, not how you think it should be done.

    Please take a moment to amend your thread title. Make sure that the title properly explains your request. Your title should be explicit and not be generic (this includes function names used without an indication of what you are trying to achieve).

    Please see Forum Rule #1 about proper thread titles and adjust accordingly. To edit the thread title, open the original post to edit and then click on Go Advanced (bottom right) to access the area where you can edit your title.

    (Note: this change is not optional. No help to be offered until this moderation request has been fulfilled.)
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  4. #4
    Registered User
    Join Date
    05-08-2020
    Location
    Lublin, Poland
    MS-Off Ver
    2003, 2007, 2010, 2019 (home); 2002, 2007, 2016, 365 (work)
    Posts
    69

    Re: Time formula

    The "Time" data are in seconds, I guess?
    Przemyslaw Kowalik, Lublin Univ. of Technology

  5. #5
    Forum Moderator - RIP Richard Buttrey's Avatar
    Join Date
    01-14-2008
    Location
    Stockton Heath, Cheshire, UK
    MS-Off Ver
    Office 365, Excel for Windows 2010 & Excel for Mac
    Posts
    29,464

    Re: Time formula

    ...that's really neat Dave. I like it. Not seen that technique before.
    Richard Buttrey

    RIP - d. 06/10/2022

    If any of the responses have helped then please consider rating them by clicking the small star icon below the post.

  6. #6
    Forum Expert
    Join Date
    10-10-2016
    Location
    Sheffield
    MS-Off Ver
    365 and rarely 2016
    Posts
    3,212

    Re: Time formula

    I can't remember where I saw it, it does get a bit messy tho and arguably an if statement for each term could be needed so the text can be excluded. Such as the top line still returning minutes

  7. #7
    Registered User
    Join Date
    05-08-2020
    Location
    Lublin, Poland
    MS-Off Ver
    2003, 2007, 2010, 2019 (home); 2002, 2007, 2016, 365 (work)
    Posts
    69

    Re: Time formula

    A nice trick, but the result I see in Excel 2019 is:

    03 days h hours 1 minutes
    03 days h hours 1 minutes
    03 days h hours 1 minutes
    01 days h hours 1 minutes


    Whereas vijanand1279 didn't specify them explicitly, the format requirements seems to be
    1) no leading zeroes;
    2) no output for zero values;
    3) the singular form of the time unit if the correspoding value is 1.

    Can it be done just by using cell formating features?

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Time formula

    Administrative Note:

    Sorry chaps, but your posts do not comply with Rule #6 of our Forum RULES:

    Please do not ignore requests by Administrators, Moderators and senior forum members regarding forum rules.

    If you are unclear about the request or instruction, then send a private message to them asking for clarification.

    All Participants:

    Please do not post a reply in a thread where a Moderator or Administrator has requested an action that has not yet been complied with (e.g. title change, code tags requested, etc.). Thanks.

  9. #9
    Forum Expert
    Join Date
    10-10-2016
    Location
    Sheffield
    MS-Off Ver
    365 and rarely 2016
    Posts
    3,212

    Re: Time formula

    it can but we can not offer help till the title changes

  10. #10
    Forum Contributor
    Join Date
    01-05-2011
    Location
    India
    MS-Off Ver
    Excel 2013
    Posts
    243

    Re: Excel function to calculate minutes to days, hours, minutes

    I am looking for assistance with excel function to find the minutes converted to days, hours, minutes in the attached. In Column A I have the values and result in column B. Can this be populated with the help of excel function in Column C?

  11. #11
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Excel function to calculate minutes to days, hours, minutes

    Title fine now.

  12. #12
    Registered User
    Join Date
    05-08-2020
    Location
    Lublin, Poland
    MS-Off Ver
    2003, 2007, 2010, 2019 (home); 2002, 2007, 2016, 365 (work)
    Posts
    69

    Re: Excel function to calculate minutes to days, hours, minutes

    @vijanand1279, "minutes converted" - are you sure? The input data seem to be seconds, not minutes.

  13. #13
    Forum Expert
    Join Date
    10-10-2016
    Location
    Sheffield
    MS-Off Ver
    365 and rarely 2016
    Posts
    3,212

    Re: Excel function to calculate minutes to days, hours, minutes

    I agree its seconds if the above format is not what you desire a formula is much longer in b2

    =IF(A2/60/60/24>=1,INT(A2/60/60/24),"")&IF(A2/60/60/24>=2," days ",IF(A2/60/60/24>=1," day ",""))&IF(MOD(A2/60/60,24)>=1,INT(MOD(A2/60/60,24)),"")&IF(MOD(A2/60/60,24)>=2," hours ",IF(A2/60/60/24>=1," hour ",""))&IF(MOD(A2/60,60)>=1,INT(MOD(A2/60,60)),"")&IF(MOD(A2/60,60)>=2," minutes",IF(MOD(A2/60,60)>=1," minutes",""))

  14. #14
    Registered User
    Join Date
    05-08-2020
    Location
    Lublin, Poland
    MS-Off Ver
    2003, 2007, 2010, 2019 (home); 2002, 2007, 2016, 365 (work)
    Posts
    69

    Re: Excel function to calculate minutes to days, hours, minutes

    Yes, it must that long or similar. The only simplifications I can see at the moment are replacing /60/60/24 with /86400 and /60/60 with /3600 but the difference in length is practically invsible.

    Edit: a little bit shorter version
    =IF(INT(A2/86400),INT(A2/86400)&" day"&IF(A2/86400>=2,"s "," "),"")&IF(INT(MOD(A2/3600,24)),INT(MOD(A2/3600,24))&" hour"&IF(MOD(A2/3600,24)>=2, "s "," "),"")&IF(INT(MOD(A2/60,60)),INT(MOD(A2/60,60))&" minute"&IF(MOD(A2/60,60)>=2,"s",""),"")
    Last edited by PKowalik; 06-12-2020 at 12:01 PM.

  15. #15
    Forum Guru
    Join Date
    04-13-2005
    Location
    North America
    MS-Off Ver
    2002/XP and 2007
    Posts
    15,829

    Re: Excel function to calculate minutes to days, hours, minutes

    Are you open to alternative outputs, or are you required to use the specified text string output? Here's how I would probably do it:

    1) Use the CONVERT() function or equivalent to convert from seconds to days -> CONVERT(A2,"sec","day"). This will give a decimal day output that, for my purposes, is almost always enough.
    2) If desired, use Excel's built in sexegesimal number format to show the value as days:hours:minutes with a number format code of dd:hh:mm. Remember that the underlying value is still the fraction of a day number that the CONVERT() function returns. Usually I find this advantageous for downstream calculations that want to use this number. The text string that your example shows is nearly useless for downstream calculations.
    3) If you really like the display in the sample, you can enclose appropriate text in " " in a number format code (https://support.microsoft.com/en-us/...rs=en-us&ad=us ). Something like d" days "h" hours "m" minutes" will show something similar to your text string, but retain the underlying decimal days value.

    I don't know that it is any simpler than other suggestions, but I would tend to prefer a number format where possible so that the numeric value of the underlying value is retained.
    Quote Originally Posted by shg
    Mathematics is the native language of the natural world. Just trying to become literate.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Replies: 9
    Last Post: 10-16-2020, 04:25 PM
  2. Replies: 3
    Last Post: 08-12-2017, 01:48 AM
  3. [SOLVED] time sheet help, format TIME and formula based on the actual time entered.
    By bh mng in forum Excel Formulas & Functions
    Replies: 11
    Last Post: 12-06-2016, 01:10 PM
  4. Replies: 3
    Last Post: 12-19-2013, 06:49 AM
  5. Replies: 5
    Last Post: 04-18-2013, 11:31 AM
  6. Formula for Calculating Paid Time Off for fiscal anniversary date real time
    By 168rockwood in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 11-07-2012, 04:15 PM
  7. Replies: 2
    Last Post: 04-27-2011, 08:21 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1