Date format changes in text file?

mapfax

New Member
Joined
Apr 30, 2002
Messages
1
When a worksheet is saved as text tab delimited, the dates format(dd/mm/yyyy) are retained. However when the same is done via a macro (save as ... fileformat:=xlText) the date format has changed in the text file to mm/dd/yyyy !

Does anyone know why this happens and how I can stop it? I need the text file dates as dd/mm/yyyy.

Thanks.
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Hi mapfax,

The reason why this occurs is that the first date format (dd/mm/yyyy) is not an "Excel-compliant" date format. You can get Excel to DISPLAY dates in this form via a custom Date numberformat, but you probably have noticed that if you enter dates into Excel in this format, it will interpret these as text strings rather than dates. This occurs because these are "non-compliant" in the same way as entering today's date in the form of May-01-02 (non-compliant) rather than 01-May-02 (compliant). If you were to write the dates in this format to a csv file, then read them back into Excel, Excel would have to interpret them as text strings, not dates! So Excel writes them out in a compliant format so that it will be able to read them in later as dates, not strings. If you really want to write them out in this non-compliant format you will have to change them to Text formats, and of course accept that fact that you will only be able to read them back into Excel as the text strings that they are. To convert all dates on the active worksheet to text strings, just use the following macro:

Sub DateToDateText()
Dim strDate As String
Dim Cell As Range
For Each Cell In ActiveSheet.UsedRange
If IsDate(Cell) Then
strDate = Cell
Cell.ClearContents
Cell.NumberFormat = "@"
Cell = strDate
End If
Next Cell
End Sub

If later you want to read them in again, and want Excel to interpret them as dates, here is a macro that will convert them back:

Sub DateTextToDate()
' Converts all text-formatted cells that contain legitimate
' date strings to Excel dates
Dim Cell As Range
Dim strDate As String

For Each Cell In ActiveSheet.UsedRange
If IsDate(Cell) Then
strDate = Cell
Cell.ClearContents
Cell.NumberFormat = "General"
Cell = strDate
End If
Next Cell
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,391
Messages
6,119,247
Members
448,879
Latest member
oksanana

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