Trying to designate time frames

maxxnic

New Member
Joined
Mar 10, 2005
Messages
4
Hello to everyone!
I'm trying to designate if a worker has worked over night and specifically between the hours 22:00 and 06:00.
In Greece these hours are been managed as extra benefit, so when I enter the worker's In (C5) and Out (D5) hours I wan't it to bring me in a cell the total hours he has worked in that specific time zone.

Thanks alot for everything.
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
maxxnic,

You can use the =HOUR & = MINUTE functions to check the times.

i.e. If the start time is 21:00 in cell B3 then =HOUR(B3) will return 21

If the start time is 21:30 in cell B3 then =MINUTE(B3) will return 30

You can then use this information to calculate if the time is after 22 and before 6 (hours) time and the minutes accordingly.

Post some actual data and I will have a further look.
 
Upvote 0
Hi,

Try:

C2: =B2-A2+(B2< A2)

D2: =SUMPRODUCT((MOD(ROW(INDIRECT(A2*1440+1&":"&(B2+(B2< A2))*1440))/1440,1)< --"06:01")+(MOD(ROW(INDIRECT(A2*1440+1&":"&(B2+(B2< A2))*1440))/1440,1)>--"22:00"))/1440

format cells as [h]mm
Book1
ABCD
1Start timeEnd timeTotal timetime between 22 - 06
212:0023:0011:001:00
319:0007:0012:008:00
401:0015:0014:005:00
515:3000:3509:052:35
Sheet3
 
Upvote 0
Upvote 0
My tryout
kind regards,
Erik

EDIT
formulas don't seem to be displayed

E7 : =IF(C7< night_start,24-night_start,24-C7)
F7 : =IF(D7< =night_end,D7,night_end)
G7 : =E7+F7
H7 : =IF(C7< night_start,24-night_start,24-C7)+IF(D7<= night_end,D7,night_end)
working time night.xls
CDEFGH
2night_startnight_end
322:006:00
4
5workedmidnight
6fromtobeforeaftersumwithin single formula
723:157:000:456:006:456:45
819:007:002:006:008:008:00
920:554:302:004:306:306:30
1022:475:441:135:446:576:57
1122:005:302:005:307:307:30
1223:005:301:005:306:306:30
130:005:300:005:305:305:30
Blad1
 
Upvote 0
Calculating hours worked within time period

This formula calculates number of hours worked between 2200-0600.

=IF(OR(C10="",D10=""),0,SUMPRODUCT(((MOD(ROW(INDIRECT(C10*1440+1&":"&(D10+(D10<C10))*1440))/1440,1)<--"06:01")+(MOD(ROW(INDIRECT(C10*1440+1&":"&(D10+(D10<C10))*1440))/1440,1)>--"22:00"))/1440)*24)

I'm trying to modify it to calculate hours worked between 1800-2200, but not having much luck.

Any suggestions?
 
Upvote 0
Apologies, I'm having trouble pasting the complete formula, (should have previewed first) but it relates to the excellent solution posted by Fairwinds.

I'm trying to mod the period from being 2200-0600 to 1800-2200.

I appreciate any assistance. Thank you.
 
Upvote 0
Thanks for your suggestion fairwinds. I'm currently using a solution posted by barry houdini which works well for the current application.

=((A2 > B2)*MEDIAN(0,B2-"18:00","4:00")+MAX(0,MIN("22:00",B2+(A2 > B2))-MAX("18:00",A2)))*24

I'll certainly give yours a try too. It's a good learning experience for me in seeing the different approaches.

Thanks again for your help!
 
Upvote 0

Forum statistics

Threads
1,223,098
Messages
6,170,099
Members
452,301
Latest member
QualityAssurance

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top