+ Reply to Thread
Results 1 to 9 of 9

How long have we had this product?

  1. #1
    Registered User
    Join Date
    03-21-2013
    Location
    Texas, United States
    MS-Off Ver
    Excel 2010
    Posts
    6

    How long have we had this product?

    So I was given the task of finding out how many business hours we have had products in. I am average with Excel but no where near where I probably need to be to make the right formula. Hoping you guys can help me out.

    Our current database is set up like this

    A1 - Start Time 2/19/2013 8:42:30 PM
    B1 - End Time 2/21/2013 12:20:26 PM
    C1 - Total Time 39:37:56 (Retrived with the Formula =B1-A1)


    The problem with this is that we are only opened from 7am-7pm Monday through Friday. The current formula takes in account weekends and 24 hour days.

    So, I did a bit of searching and found a formula that is close to what I want.

    =WORKDAY(A1,CEILING((B1+MOD(A1,1)-D$1)/(E$1-D$1),1)-1)+MOD(A1,1)+B1-CEILING(MOD(A1,1)+B1-D$1,E$1-D$1)+E$1-D$1

    A1 - Is my start time
    B1 - Is my end time
    C1 - Should display total time we had product
    D1 - Time we open
    E1 - Time we close

    It seems to have an error with certain issues. For example, one of the ones that wont work is

    A1 - 2/22/2013 18:24
    B1 - 2/26/2013 13:11
    D1 - 7:00:00
    E1- 19:00:00

    My C1 cell shows 7:36:17 which cannot be right because the time in which we had the product covers a full Monday, which means we should have to add another 12 hours to the C1 total.

    Not sure why my formula is messing up on larger dates and not the smaller ones. Again, any help would be appreciated. Thanks.
    Last edited by evan_draughon; 03-21-2013 at 04:14 PM.

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: How long have we had this product?

    Maybe:

    =IF(NETWORKDAYS(A2,B2)<2,MOD(B2,1)-MOD(A2,1),($E$1-MOD(A2,1)+MOD(B2,1)-$D$1)+((NETWORKDAYS(A2,B2)-2)*10/24))

    http://screencast.com/t/dxlkRsKXL
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  3. #3
    Registered User
    Join Date
    03-21-2013
    Location
    Texas, United States
    MS-Off Ver
    Excel 2010
    Posts
    6

    Re: How long have we had this product?

    Let me give it a try, thanks JBeaucaire

  4. #4
    Registered User
    Join Date
    03-21-2013
    Location
    Texas, United States
    MS-Off Ver
    Excel 2010
    Posts
    6

    Re: How long have we had this product?

    It is still off somehow. Here is the sample page that I am working with.Working Formula.xls

  5. #5
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: How long have we had this product?

    Try:

    =NETWORKDAYS(A1,B1)*(($E$1-$D$1))+($E$1-(MOD(A1,1)))+(MOD(B1,1)-$D$1)

  6. #6
    Registered User
    Join Date
    03-21-2013
    Location
    Texas, United States
    MS-Off Ver
    Excel 2010
    Posts
    6

    Re: How long have we had this product?

    Still off. The last date in this file is like a week long and it is only showing 17 hours. Ill post the updated form so you can see what it shows. Working Formula.xls

  7. #7
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: How long have we had this product?

    1) You didn't put in my suggested formula, makes me sad.

    Try this one instead: =((NETWORKDAYS(A1,B1)-2)*(($E$1-$D$1)))+($E$1-(MOD(A1,1)))+(MOD(B1,1)-$D$1)

    2) You need to correct the formatting of the cells so they will show more than 24 hours. The cell format should be:

    Custom: [h]:mm:ss

  8. #8
    Registered User
    Join Date
    03-21-2013
    Location
    Texas, United States
    MS-Off Ver
    Excel 2010
    Posts
    6

    Re: How long have we had this product?

    I had the formula in, I just linked the wrong file. Everything seems to be working well. There are still a few hiccups, but for the most part I have been able to figure them out. Thank you for your help again.

  9. #9
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: How long have we had this product?

    Always glad to assist.
    If that takes care of your original query, please select Thread Tools from the menu above and mark the thread as solved. Thanks.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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