Last week over at the Chandoo.org Forums, Birko asked a question about How to Import some Numbers as Times.
“I have imported some data that comes in as a number that I need to convert to h:mm. The data string will be either 1,3,4,5,6 integers long and looks like this…eg
Imported Need to equal this
Number h:mm
0 0:00
100 0:01
1000 0:10
10900 1:09
235900 23:59
Can someone please provide a smart formula to convert this (assume data is in cell A1).”
Today in Formula Forensics we will look at how this problem was solved, and the solution which may surprise you.
Importing Numbers as Times.
When I first saw this data I start by looking at patterns.
Working backwards through the list
I can see that 235900 is 23 Hrs, 59 Min and 0 second
I can see that 10900 is 1 Hr, 9 Min and 0 second
I can see that 1000 is 0 Hrs, 10 Min and 0 second
I can see that 100 is 0 Hr, 1 Min and 0 second
I can see that 0 is 0 Hr, 0 Min and 0 second
I then start to think about how to extract the Hours, Minutes and seconds independently from the Text using a series of Left, Right and Mid functions, and quickly realised that due to the varying lengths of the strings, That they will end up being complex formulas as I will need to allow for each string length.
What if I pad the strings with leading 0’s and then extract them.
That is possible, but as a single formula it will be long and cumbersome as the padding has to occur a number of times for each Hour, Minute and Second as part of the Time() function.
So padding may work but is cumbersome, then a bright light moment
What about I use the Text function to do the padding.
And I quickly posted the following formula:
=(LEFT(TEXT(A1,"000000"),2)/24)+(MID(TEXT(A1,"000000"),3,2)/1440)+(RIGHT(TEXT(A1,"000000"),2)/(24*3600))
As Time is just a number between 0 = midnight and 0.999999 = 11:59:59 pm, I can extract the Hours, Minutes and seconds separately and then simply add them together to get the actual time
I Can use the Text function to display the Strings in a consistent format that allows me to use the Left, Mid and Right functions to retrieve the Hours minutes and Seconds from the appropriate places.
Lets work through this formula section by section and see what is going on.
Hours
The Hours component of the formula is
=(LEFT(TEXT(A1,"000000"),2)/24)+(MID(TEXT(A1,"000000"),3,2)/1440)+(RIGHT(TEXT(A1,"000000"),2)/(24*3600))
=(LEFT(TEXT(A1,"000000"),2)/24)
Working from the middle out, this formula takes the value in A1 and displays it as a Number with the format “000000”
So using our data
235900 will convert to 235900
10900 will convert to 010900
1000 will convert to 001000
We can now use a Left() function to extract the hours from the first 2 characters of the converted string
Using our examples:
Left(235900,2) = 23
Left(010900,2) = 01
Left(001000,2) = 00
To convert hours to a Time we simply divide by 24
Minutes
The Minutes component of the formula is
=(LEFT(TEXT(A1,"000000"),2)/24)+(MID(TEXT(A1,"000000"),3,2)/1440)+(RIGHT(TEXT(A1,"000000"),2)/(24*3600))
=MID(TEXT(A1,"000000"),3,2)/1440
Once again, Working from the middle out, this formula takes the value in A1 and displays it as a Number with the format “000000”
So using our data
235900 will convert to 235900
10900 will convert to 010900
1000 will convert to 001000
We can now use a Mid() function to extract the minutes from the middle 2 characters of the converted string
Mid(235900,3,2) = 59
Mid(010900,2) = 09
Mid(001000,2) = 10
To convert Minutes to a Time we simply divide by 1440 (1440 is how many minutes are in a day = 24 * 60)
Seconds
The Seconds component of the formula is
=(LEFT(TEXT(A1,"000000"),2)/24)+(MID(TEXT(A1,"000000"),3,2)/1440)+(RIGHT(TEXT(A1,"000000"),2)/(24*3600))
=RIGHT(TEXT(A1,"000000"),2)/(24*3600))
Once again, Working from the middle out, this formula takes the value in A1 and displays it as a Number with the format “000000”
So using our data
235900 will convert to 235900
10900 will convert to 010900
1000 will convert to 001000
We can now use a Right() function to extract the minutes from the middle 2 characters of the converted string
Right(235900,3,2) = 00
Right(010900,2) = 00
Right(001000,2) = 00
To convert Seconds to a Time we simply divide by 86400 (86,400 is how many seconds are in a day = 24 * 60 * 60)
Total Time
To get the total Time we simply add the Hour, Minutes and Seconds together
=(LEFT(TEXT(A1,"000000"),2)/24)+(MID(TEXT(A1,"000000"),3,2)/1440)+(RIGHT(TEXT(A1,"000000"),2)/(24*3600))
Download
You can download a copy of the above file and follow along, Download Here.
Formula Forensics “The Series”
You can learn more about how to pull Excel Formulas apart in the following posts
Formula Forensics Needs Your Help
I urgently need more ideas for future Formula Forensics posts and so I need your help.
If you have a neat formula that you would like to share and explain, try putting pen to paper and draft up a Post like above or;
If you have a formula that you would like explained but don’t want to write a post also send it to Chandoo or Hui.

















13 Responses to “Convert fractional Excel time to hours & minutes [Quick tip]”
Hi Purna..
Again a great tip.. Its a great way to convert Fractional Time..
By the way.. Excel has two great and rarely used formula..
=DOLLARFR(7.8,60) and =DOLLARDE(7.48,60)
basically US Account person uses those to convert some currency denomination.. and we can use it to convert Year(i.e 3.11 Year = 3 year 11 month) and Week(6.5 week = 6 week 5 days), in the same manner...
This doesn't work for me. When applying the custom format of [h]:mm to 7.8 I get 187:12
Any ideas why?
@Jason
7.8 in Excel talk means 7.8 days
=7.8*24
=187.2 Hrs
=187 Hrs 12 Mins
If you follow Chandoo's instructions you will see that he divides the 7.8 by 24 to get it to a fraction of a day
Simple, assuming the fractional time is in cell A1,
Use below steps to convert it to hours & minutes:
1. In the target cell, write =A1/24
2. Select the target cell and press CTRL+1 to format it (you can also right click and select format cells)
3. Select Custom from “Number” tab and enter the code [h]:mm
4. Done!
Hi, sorry to point this out but Column C Header is misspelt 'Hours Palyed'
good one
So how do I go the other way and get hours and minutes to fractional time?
If you have 7.5 in cell A1,
- Use int(A1) to get the hours.
- Use mod(A1,1)*60 to get minutes.
If you have 7:30 (formatted as time) in A1
- Use hours(a1) to get hours
- Use minutes(a1) to get minutes.
I had the same issue. You can solve it by changing the format as described above:
Right click cell > Format Cells > (In Number tab) > Custom > Then enter the code [h]:mm
([hh]:mm and [hhh]:mm are nice too if you want to show leading zeros)
Thanks guys, these are the tips I'm looking for.
...dividing the number of minutes elapsed by the percent change is my task - "int" is the key this time
It doesnt work for greater than 24 hours
It returns 1:30 for 25.5 hours. It should have returned 25:30
Ideally I would right function as
=QUOTIENT(A1,1)&":"&MOD(A1,1)*60
Sorry, replied to wrong comment....
----
I had the same issue. You can solve it by changing the format as described above:
Right click cell > Format Cells > (In Number tab) > Custom > Then enter the code [h]:mm
([hh]:mm and [hhh]:mm are nice too if you want to show leading zeros)
Clever use of MOD here to extract the decimal part of a number. Divide a number containing a decimal by 1 and return the remainder. Humm. Very clever.
Thanks very much, extremely useful !