Time Format

S.H.A.D.O.

Well-known Member
Joined
Sep 6, 2005
Messages
1,915
Hi everyone,

I would like to be able to enter a start time for example as 6.15 ( with a dot as opposed to a : ) and a finish time as 14.45. I would then like to calculate the total number of hours worked please ( the previous would equate to 8.50 hours ).

Any help will be greatly appreciated.
All the Best.
SHADO
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
If start time is in A1 and end time in B1 try

=MOD(SUBSTITUTE(B1,".",":")-SUBSTITUTE(A1,".",":"),1)*24

format as number
 

S.H.A.D.O.

Well-known Member
Joined
Sep 6, 2005
Messages
1,915
Barry,

The only thing is that if I input the start time as 5.00 and the finish time as 11.00, the formula returns a zero hours worked.

Erik,

The 8.50 equates to 8 and a half hours worked.

Thank you both for the replies.
All the Best.
SHADO
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825

ADVERTISEMENT

Barry,
The only thing is that if I input the start time as 5.00 and the finish time as 11.00, the formula returns a zero hours worked.

OK then try

=MOD(SUBSTITUTE(TEXT(B1,"0.00"),".",":")-SUBSTITUTE(TEXT(A1,"0.00"),".",":"),1)*24
 

erik.van.geit

MrExcel MVP
Joined
Feb 1, 2003
Messages
17,832
Hi,

I cannot get Barries trick to work, will try again.

This works for me, but the longer looking at it, the more I wouldn't advise such a counterintuitive layout.
  A     B     C       
1 start stop  elapsed 
2 6,15  14,45 8,5     
3 5     11    6       
4 9     21,3  12,5    

Calculation

[Table-It] version 05 by Erik Van Geit
Code:
RANGE FORMULA (1st cell)
C2:C4 =TRUNC(B2)-TRUNC(A2)+ROUND((B2-TRUNC(B2)-A2+TRUNC(A2))*100,0)/60

[Table-It] version 05 by Erik Van Geit

not talking of the problems when starting at 23.00 and ending at 4.00
kind regards,
Erik
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825

ADVERTISEMENT

Another way would be

=MOD(DOLLARDE(B1,60)-DOLLARDE(A1,60),24)

.....although DOLLARRDE requires Analysis ToolPak
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
not talking of the problems when starting at 23.00 and ending at 4.00

The formulas I posted will all take care of shifts which pass from one day to the next :biggrin:
 

erik.van.geit

MrExcel MVP
Joined
Feb 1, 2003
Messages
17,832
not talking of the problems when starting at 23.00 and ending at 4.00
quickly fixed that one
Code:
RANGE FORMULA (1st cell)
C2:C4 =TRUNC(B2)-TRUNC(A2)+ROUND((B2-TRUNC(B2)-A2+TRUNC(A2))*100,0)/60+(A2>B2)*24

[Table-It] version 05 by Erik Van Geit
(perhaps missing some obvious change to make it shorter)
 

S.H.A.D.O.

Well-known Member
Joined
Sep 6, 2005
Messages
1,915
Hi Barry,

OK then try :-

=MOD(SUBSTITUTE(TEXT(B1,"0.00"),".",":")-SUBSTITUTE(TEXT(A1,"0.00"),".",":"),1)*24
works Perfectly, thank you. It is exactly what I was after.

Thank you Barry & Erik for your time & effort on this.
Have a good evening.

All the Best.
SHADO
 

Forum statistics

Threads
1,137,298
Messages
5,680,695
Members
419,927
Latest member
Axtros

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
Top