+ Reply to Thread
Results 1 to 14 of 14

Split breakdown time between shifts

  1. #1
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Question Split breakdown time between shifts

    Hi Forum

    I come with a problem that has been raised by my manager, that I can solve in my head, but I cannot declare that in any way to excel formula language.
    I have solved it but really not in the way It is supposed to be.

    We have machines that may fail and breakdown, if it happens we register a ticket that declares the date and time that malfunction started.
    As we know when malfunction stopped, and we have a specific breakdown time duration, we want to assign breakdown time to shift that was working at the time.
    I solved this in the way I assigned the whole breakdown time to the shift that malfunction started, but the problem is I don't know how to split this time between more than one shift.
    Let me give you an example:
    We have 3 shifts working:
    6-14 - Call it to shift A
    14-22 - call it to shift B
    22-6 - call it to shift C
    If malfunction started at 12 and lasted for 16hours I have to assign breakdown time:
    - A 2 hours
    - B 8 Hours
    - C 4 Hours

    Magicians helping highly welcome, and appreciated.
    Attached Files Attached Files

  2. #2
    Forum Contributor
    Join Date
    05-18-2021
    Location
    London, Ontario
    MS-Off Ver
    365
    Posts
    115

    Re: Split breakdown time between shifts

    Ok try this:

    6 columns

    A Hours downtime (e.g. 16) (format as General)
    B Time it went down (e.g. 12:00:00 PM) (format as custom)
    C Translate time so that the formula isn't overly complicated for shift C: =IF(24*B2 - 6>0, 24*B2 - 6, 24 + 24*B2 - 6) (format as General)
    D Down time during shift A: =IF(C2< 8, IF(A2>8, 8 - C2, A2), 0) (format as General)
    E Down time during shift B: =IF(C2<16,IF(A2-D2>8,16-C2-D2,A2-D2), 0) (format as General)
    F Down time during shift C: = IF(C2 < 24, IF(A2-E2-D2 > 8, 24 - C2 -D2 - E2, A2-E2-D2),0) (format as General)
    Last edited by dohvakin123; 05-20-2021 at 11:45 AM. Reason: fixed

  3. #3
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Re: Split breakdown time between shifts

    Quote Originally Posted by dohvakin123 View Post
    Ok try this:

    6 columns

    A Hours downtime (e.g. 16) (format as General)
    B Time it went down (e.g. 12:00:00 PM) (format as custom)
    C Translate time so that the formula isn't overly complicated for shift C: =IF(24*B2 - 6>0, 24*B2 - 6, 24 + 24*B2 - 6) (format as General)
    D Down time during shift A: =IF(C2< 8, IF(A2>8, 8 - C2, A2), 0) (format as General)
    E Down time during shift B: =IF(C2<16,IF(A2-D2>8,16-C2-D2,A2-D2), 0) (format as General)
    F Down time during shift C: = IF(C2 < 24, IF(A2-E2-D2 > 8, 24 - C2 -D2 - E2, A2-E2-D2),0) (format as General)
    Thanks for your time, unlucky this works until we're not exceeding 23 hours, and this happens often. If we're over it, it just shows 8 hours for all the shifts :/

  4. #4
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Re: Split breakdown time between shifts

    Probably not possible by formulas, maybe vba will solve this.

  5. #5
    Forum Contributor
    Join Date
    05-18-2021
    Location
    London, Ontario
    MS-Off Ver
    365
    Posts
    115

    Re: Split breakdown time between shifts

    Do you mean if it goes over Shift C into the next day of Shift A?

  6. #6
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Re: Split breakdown time between shifts

    Exceeding shift C doesnt goes to A as it is supposed to be.

  7. #7
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 2019
    Posts
    17,422

    Re: Split breakdown time between shifts

    Looking at the file attached to post #1, it seems that the time the malfunction starts is in column B and the duration is in column D given in fractions of an hour i.e. 0.29 in cell D2 represents 17 minutes.
    I also seems that column F shows the shift in which the malfunction ends.
    Perhaps you could show us manually how you solve the split breakdown in your head, for a few of the rows such as row 37, 1392, 2323 and 2428.
    We may then be in a better position attempt to write formulas/code that would automate your process.
    Let us know if you have any questions.
    Consider taking the time to add to the reputation of everybody that has taken the time to respond to your query.

  8. #8
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Re: Split breakdown time between shifts

    So with an example:
    Having information on when the breakdown started and the time it lasted I want to know how much breakdown time I had for each shift every day.
    Attachment 734188 - screenshot
    I have marked each breakdown in a different color, in the right table I have entered a total time of breakdown that was on a certain shift.
    Purple color means total, and values in brackets are highlighted with colors to explain what total value consists of.
    Attached Files Attached Files

  9. #9
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Re: Split breakdown time between shifts

    Kindly asking once again to support with this one :/

  10. #10
    Forum Contributor
    Join Date
    05-18-2021
    Location
    London, Ontario
    MS-Off Ver
    365
    Posts
    115

    Re: Split breakdown time between shifts

    this should be closer to what you're looking for. if you need it to extend further just add more columns and drag that formula horizontally
    Attached Files Attached Files

  11. #11
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 2019
    Posts
    17,422

    Re: Split breakdown time between shifts

    @dohvakin123, Very nice work. I hope that it is alright for me collaboratively expand on what you have done.
    1. Two rows are added: Row 1 displays the date using: =IF(COUNTIFS($F1:F1,F1)<=2,F1,SUM(F1,1)) and row 2 is filled using: =SUM(F2,8)
    2. The formula for F4 and down is: =IF(E4< F$2, IF(C4>8, F$2 - E4, C4), 0)
    3. The formula for G4, down and across is: =IF($E4<G$2,IF(OR(SUM($F4:F4)=0,$C4-SUM($F4:F4)>8),G$2-SUM($E4:F4),$C4-SUM($F4:F4)), 0)
    4. The formula to sum the hours per day and shift is: =SUMPRODUCT(($F$4:$W$7)*($F$1:$W$1=$Y3)*($F$3:$W$3=Z$2))
    To again acknowledge that dohvakin123 did the heavy lifting on this.
    Let us know if you have any questions.

  12. #12
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,513

    Re: Split breakdown time between shifts

    Pl see file
    All are ARRAY formulas
    IN H2
    Please Login or Register  to view this content.
    In I2
    Please Login or Register  to view this content.
    In J2
    Please Login or Register  to view this content.
    All copied down
    To enter ARRAY formula
    Copy and paste the formula in cell
    Press F2
    Press Ctrl+Shift+Enter together
    Excel covers the formula with {}.
    Attached Files Attached Files
    Pl note
    Array formula should be confirmed with Ctrl+Shift+Enter keys together.
    If answere is satisfactory press * to add reputation.

  13. #13
    Registered User
    Join Date
    04-29-2021
    Location
    Wroclaw
    MS-Off Ver
    2013
    Posts
    9

    Smile Re: Split breakdown time between shifts

    Okay, so now, here comes huge thanks for you guys, dovakin123 many much thanks for your time to help me out,
    it came that kvsrinvsamurthy came with an idea that perfectly matched my needs,
    after implementing his formula to my complete worksheet consisting of data about thousands of breakdowns it worked super well.
    You guys are awesome!!!!

    All of you got reputation which is obvious, some day I hope I will be able to help you as well

  14. #14
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,513

    Re: Split breakdown time between shifts

    Thanks for feedback and 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. Replies: 4
    Last Post: 02-25-2020, 07:21 PM
  2. Replies: 3
    Last Post: 02-25-2020, 12:04 PM
  3. Schedule with Split Shifts, and Sort by times in/out
    By russellm84 in forum Excel General
    Replies: 4
    Last Post: 12-19-2018, 05:27 PM
  4. [SOLVED] complex split formula needs amendment for breakdown per column
    By JEAN1972 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 11-28-2018, 01:54 AM
  5. Hours worked on Different Shifts - Breakdown on overtime and ordinary
    By Rangedale in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 07-22-2015, 12:50 AM
  6. Working hours - identify and split in different rewards shifts
    By bartho87 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 08-05-2014, 12:11 PM
  7. Adding hours for split shifts
    By fingus in forum Excel General
    Replies: 7
    Last Post: 07-07-2010, 05:00 PM

Tags for this Thread

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