Help converting weird date format

petersw

New Member
Joined
Sep 22, 2011
Messages
10
I've got a file with dates entered as year-month:

15-May
16-Mar
7-Jun

These are meant to represent

5/1/2015
3/1/2016
6/1/2007

Unfortunately, they were saved in a date format that makes Excel see them as being a month and day in 2019:

5/15/2019
3/16/2019
6/7/2019

How can I convert them into the correct date format (15-May should be 5/1/2015, as I have only month and year for each value)?

Thanks!!!
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
Assuming all of your dates are screwed up this way, give this macro a try. Note that I assumed your dates are located in Column A starting on Row 1... if this assumption is incorrect, then change the red text to the appropriate values.
Code:
Sub FixDates()
  Dim Col As String, StartRow As Long, LastRow As Long, R As Long
  Col = "[B][COLOR="#FF0000"]A[/COLOR][/B]"
  StartRow = [B][COLOR="#FF0000"]1[/COLOR][/B]
  LastRow = Cells(Rows.Count, Col).End(xlUp).Row
  For R = StartRow To LastRow
    Cells(R, Col).Value = DateSerial(Day(Cells(R, Col)), Month(Cells(R, Col)), 1)
  Next
End Sub
 
Upvote 0
Messy ...

A​
B​
C​
1​
15-May
01 May 2015​
B1: =--(1 & MID(A1, FIND("-", A1) + 1, 4) & LEFT(A1, FIND("-", A1) - 1))
2​
16-Mar
01 Mar 2016​
3​
7-Jun
01 Jun 2007​
 
Upvote 0
Try this

<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:154.93px;" /><col style="width:132.12px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >Actual</td><td >Result</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">05/15/2019</td><td style="text-align:right; ">01/05/2015</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">03/16/2019</td><td style="text-align:right; ">01/03/2016</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">06/07/2019</td><td style="text-align:right; ">01/06/2007</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>Formeln der Tabelle</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 >Zelle</td><td >Formel</td></tr><tr><td >B2</td><td >=DATE("20"&TEXT(A2,"dd"),MONTH(A2),1)</td></tr></table></td></tr></table>
 
Upvote 0
DanteAmor's solution worked perfectly! Thanks to everyone, but the challenge was that the dates were actually in serial format with the wrong date. Rebuilding it with the date function did the trick!
 
Upvote 0
DanteAmor's solution worked perfectly! Thanks to everyone, but the challenge was that the dates were actually in serial format with the wrong date. Rebuilding it with the date function did the trick!

I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,487
Messages
6,113,943
Members
448,534
Latest member
benefuexx

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