+ Reply to Thread
Results 1 to 8 of 8

Calculating Target Date/Time Based on Start date and hours - Excel 2007

  1. #1
    Registered User
    Join Date
    09-01-2018
    Location
    Bangalore
    MS-Off Ver
    2016
    Posts
    7

    Calculating Target Date/Time Based on Start date and hours - Excel 2007

    The solution provided by Daddylonglegs at the link below does not work for this particular scenario. Any help will be greatly appreciated.

    excelforum.com/excel-formulas-and-functions/979700-calculating-target-date-time-based-on-start-date-and-hours-excel-2007-a.html
    I'm trying to calculate enddate and time when start date and duration is provided. The solution provided by Daddylonglegs works perfectly but something goes wrong in the below scenario.

    The enddate & time does not calculate correctly if the time is 2:00 PM and the duration is 4 hours. Let me explain...

    StartDate&Time = 24 Sep 2:00 PM
    Duration = 4 hours
    WorkHours is 10:00 to 18:00

    EndDate&Time shows as 25 Sep 10:00 AM instead of 24 Sep 06:00 PM

    I'm racking my brains over this and can't figure out why it doesn't calculate correctly for 2:00 PM (any other time between 6-18:00 works fine). Your help will be greatly appreciated.

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    Post a sample sheet in this thread showing the problem.

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Registered User
    Join Date
    09-01-2018
    Location
    Bangalore
    MS-Off Ver
    2016
    Posts
    7

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    Attaching example file.
    Attached Files Attached Files

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    Depending on the chosen start time/duration, Excels way of counting (floating point arithmetic) can sometimes give rise to errors. A start time of 14:00 and a duration of 4 hrs is one. 11:00 and 1 hr is another.

    Other combinatons, as you pointed out (start time of 12:00 and 6 hrs duration) work fine. To fix this, some additional rounding phrases need to be added to the formula:

    =WORKDAY(A2,CEILING(ROUND(1440*(B2/24+MOD(A2,1)-E$2)/(F$2-E$2),0)/1440,1)-1)+ROUND(1440*(MOD(A2,1)+B2/24),0)/1440-CEILING(ROUND(1440*(MOD(A2,1)+(B2/24-E$2)),0)/1440,ROUND(1440*(F$2-E$2),0)/1440)+F$2-E$2

    see sheet.

  5. #5
    Registered User
    Join Date
    09-01-2018
    Location
    Bangalore
    MS-Off Ver
    2016
    Posts
    7

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    Glenn You are a superstar, this works. But will you be able to update the formula to account for holidays which was available in the original formula that Daddylonglegs provided? I'm listing it here...I'm asking this as I'm translating the entire formula to a macro that I'm slowly building. Thanks

    =WORKDAY(A2,CEILING((B2/24+MOD(A2,1)-E$2)/(F$2-E$2),1)-1,D$2:D$10)+MOD(A2,1)+B2/24-CEILING(MOD(A2,1)+B2/24-E$2,F$2-E$2)+F$2-E$2

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    I did leave them out... as your attachment referred to blank cells.

    =WORKDAY(A2,CEILING(ROUND(1440*(B2/24+MOD(A2,1)-E$2)/(F$2-E$2),0)/1440,1)-1,$D$2:$D$10)+ROUND(1440*(MOD(A2,1)+B2/24),0)/1440-CEILING(ROUND(1440*(MOD(A2,1)+(B2/24-E$2)),0)/1440,ROUND(1440*(F$2-E$2),0)/1440)+F$2-E$2

    will do it.

    So... You're welcome.



    If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

  7. #7
    Registered User
    Join Date
    09-01-2018
    Location
    Bangalore
    MS-Off Ver
    2016
    Posts
    7

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    The formula works like a charm. Glen, Thank you so much for your help.

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: Calculating Target Date/Time Based on Start date and hours - Excel 2007

    You're welcome and thanks for the rep.

+ 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. [SOLVED] Calculating Target Date/Time Based on Start date and hours - Excel 2007
    By chinraj in forum Excel Formulas & Functions
    Replies: 14
    Last Post: 12-09-2019, 01:43 AM
  2. Replies: 8
    Last Post: 01-31-2016, 10:14 AM
  3. Replies: 9
    Last Post: 02-15-2015, 07:32 PM
  4. [SOLVED] Calculate number of hours from Start date and time and End date and time
    By sathyasun in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 06-28-2013, 01:04 AM
  5. Calculating END time based on start time, breaks, and hours to complete
    By sweedey in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 02-01-2012, 11:29 AM
  6. Calculate START date based on duration (work hours) and END date
    By kaaver in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 07-06-2010, 12:21 PM
  7. [SOLVED] Calculating days & time left from start date/time to end date/time
    By marie in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 12-07-2005, 10:40 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