Text DateFixer

mole999

Moderator
Joined
Oct 23, 2004
Messages
9,899
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?
 

Jeffrey Mahoney

Well-known Member
Joined
May 31, 2015
Messages
1,604
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
 

mole999

Moderator
Joined
Oct 23, 2004
Messages
9,899
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
 

Jeffrey Mahoney

Well-known Member
Joined
May 31, 2015
Messages
1,604
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
 

mole999

Moderator
Joined
Oct 23, 2004
Messages
9,899
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:

Jeffrey Mahoney

Well-known Member
Joined
May 31, 2015
Messages
1,604
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.
 

Forum statistics

Threads
1,082,305
Messages
5,364,401
Members
400,800
Latest member
germanpbv

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top