Text DateFixer

mole999

Well-known Member
Joined
Oct 23, 2004
Messages
10,524
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
Just imported a load of CSV values that came across as 1/15/2019 12:22 date and time

I was following > https://www.mrexcel.com/forum/excel-questions/1086344-formatting-dates.html which works when no time value is involved.
Just wondering if a small vba script could be developed that would strip the time value and then invert the date to 15/01/2019. something on the lines of
Code:
Sub nameswaper()
On Error Resume Next
   Dim St As String, i As Long
   St = ActiveCell.Value
   i = InStrRev(St, " ")
   ActiveCell.Offset(, 0).Value = UCase(Right(St, Len(St) - i)) & " " & WorksheetFunction.Proper(Left(St, i - 1))
End Sub.
I'm sure there would be many users for this simple concept
=IF(ISTEXT(D1020),DATEVALUE(MID(D1020,FIND("/",D1020,1)+1,2)&"/"&SUBSTITUTE(LEFT(D1020,2),"/","")&"/"&MID(D1020,FIND("/",D1020,4)+1,4)),D1020) works as intended, just would like to wrap in VBA
Any thoughts?
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
It sounds like you want to use some code, but there may be an easier way. The cells seem to contain text, true? You want to turn those into dates without the time. There are options.

When I import SAP data, for some reason it always formats the date cells as text, sheesh

You can highlight the dates and DATA-Text To Columns-Finish. The text to columns feature without changing any parameters will change the date as text to a date as a serial number. Now you can format the date as you like by switching the Month and day in the custom number formatting.

If you still want code, I can help

Jeff
 
Upvote 0
Jeffrey
the existing columns are already in existence so pushing to additional columns to build and then bring back is wasteful of time. I'm only updating every few months so i don't mind a bit of work, and to me on a right click menu to just have the cell reformat to me is the quickest way.

the formula provided above works, just trying to pull it together on the selected cell would take but a moment from a menu or right click
 
Upvote 0
A simple version of code:

Code:
Sub ChangeIntoDate()
  Dim Cel As Range
  Dim St As String
  Dim Dt As Date
  Dim s1 As Integer
  Dim s2 As Integer
  Dim s3 As Integer
  Dim m As Long
  Dim d As Long
  Dim y As Long
  
  For Each Cel In Selection
    St = Cel.Value
    s1 = InStr(St, "/")
    s2 = InStr(s1 + 1, St, "/")
    s3 = InStr(s2 + 1, St, " ")
    If s3 = 0 Then s3 = Len(St)
    
    d = Val(Mid(St, s1 + 1, s2 - (s1 + 1)))
    m = Val(Left(St, s2 - 1))
    y = Val(Mid(St, s2 + 1, s3 - (s2 + 1)))
    
    Dt = DateSerial(y, m, d)
    Cel.Value = Format(Dt, "dd/mm/yyyy")
    
  Next Cel
  
End Sub
 
Upvote 0
Brilliant, I wasn't even thinking loop, just the ability to do a change in the cell :)

just don't run it twice, note to self
 
Last edited:
Upvote 0
A note to your response #3 . The text to columns feature will simply overwrite your current date values without having to copy to a different column.
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,263
Members
452,627
Latest member
KitkatToby

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