Changing Military time to standard time

datadummy

Active Member
Joined
Mar 16, 2017
Messages
312
Office Version
  1. 365
Platform
  1. Windows
I am attempting to change military time to standard time but am having issues when the time starts with a 0, for example 0327 is changing to 8:07 AM rather than 3:27 AM. Here is the current formula I have used, =TIMEVALUE(LEFT(G2,2)&":"&MID(G2,3,2)&":"&RIGHT(G2,2)). Any thoughts on how to achieve this without using VBA?
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
Try this:

<b>Sheet</b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:80px;" /><col style="width:80px;" /><col style="width:103px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >G</td><td >H</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td >Militar</td><td >Standard</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td > </td><td style="text-align:right; ">327</td><td style="text-align:right; ">03:27:00 a.m.</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td > </td><td style="text-align:right; ">1028</td><td style="text-align:right; ">10:28:00 a.m.</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td > </td><td style="text-align:right; ">1516</td><td style="text-align:right; ">03:16:00 p.m.</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td > </td><td style="text-align:right; ">32115</td><td style="text-align:right; ">03:11:15 a.m.</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td > </td><td style="text-align:right; ">131816</td><td style="text-align:right; ">01:18:16 p.m.</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td > </td><td style="text-align:right; ">1816451</td><td >It is not an hour</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td > </td><td style="text-align:right; ">12</td><td >It is not an hour</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Formula</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >H2</td><td >=IF(LEN(G2)=6,TIMEVALUE(LEFT(G2,2)&":"&MID(G2,3,2)&":"&RIGHT(G2,2)),IF(LEN(G2)=5,TIMEVALUE(LEFT(G2,1)&":"&MID(G2,3,2)&":"&RIGHT(G2,2)),IF(LEN(G2)=4,TIMEVALUE(LEFT(G2,2)&":"&MID(G2,3,2)),IF(LEN(G2)=3,TIMEVALUE(LEFT(G2,1)&":"&MID(G2,2,2)),"It is not an hour"))))</td></tr></table></td></tr></table> <br /><br />
 
Upvote 0
Try this:

Sheet

AGH
1 MilitarStandard
2 32703:27:00 a.m.
3 102810:28:00 a.m.
4 151603:16:00 p.m.
5 3211503:11:15 a.m.
6 13181601:18:16 p.m.
7 1816451It is not an hour
8 12It is not an hour

<colgroup><col style="width: 30px; font-weight: bold;"><col style="width: 80px;"><col style="width: 80px;"><col style="width: 103px;"></colgroup><tbody>
</tbody>

Formula
CellFormula
H2=IF(LEN(G2)=6,TIMEVALUE(LEFT(G2,2)&":"&MID(G2,3,2)&":"&RIGHT(G2,2)),IF(LEN(G2)=5,TIMEVALUE(LEFT(G2,1)&":"&MID(G2,3,2)&":"&RIGHT(G2,2)),IF(LEN(G2)=4,TIMEVALUE(LEFT(G2,2)&":"&MID(G2,3,2)),IF(LEN(G2)=3,TIMEVALUE(LEFT(G2,1)&":"&MID(G2,2,2)),"It is not an hour"))))

<tbody>
</tbody>

<tbody>
</tbody>

That was amazing it worked like a charm!! Follow up question, how would you address a cell that is labeled 0035 or 0022? Is there a way to make those show as 12:35 and 12:22?
 
Upvote 0
Another way, perhaps:

A​
B​
C​
1​
Military
Standard
2​
12​
12:12 AM​
B2: =--TEXT(A2, "0\:00")
3​
327​
3:27 AM​
4​
1028​
10:28 AM​
5​
1516​
3:16 PM​
 
Upvote 0
That was amazing it worked like a charm!! Follow up question, how would you address a cell that is labeled 0035 or 0022? Is there a way to make those show as 12:35 and 12:22?

You're welcome & thanks for the feedback.

Try:

=SI(LARGO(G2)=6,HORANUMERO(IZQUIERDA(G2,2)&":"&EXTRAE(G2,3,2)&":"&DERECHA(G2,2)),SI(LARGO(G2)=5,HORANUMERO(IZQUIERDA(G2,1)&":"&EXTRAE(G2,3,2)&":"&DERECHA(G2,2)),SI(LARGO(G2)=4,HORANUMERO(IZQUIERDA(G2,2)&":"&EXTRAE(G2,3,2)),SI(LARGO(G2)=3,HORANUMERO(IZQUIERDA(G2,1)&":"&EXTRAE(G2,2,2)),SI(LARGO(G2)=2,HORANUMERO("12:"&G2),"It is not an hour")))))
 
Upvote 0

Forum statistics

Threads
1,214,819
Messages
6,121,739
Members
449,050
Latest member
excelknuckles

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