Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 2 of 2

Thread: Date format changes in text file?

  1. #1
    New Member
    Join Date
    Apr 2002
    Location
    Scotland
    Posts
    1
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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.

  2. #2
    MrExcel MVP Damon Ostrander's Avatar
    Join Date
    Feb 2002
    Location
    Denver, Colorado USA
    Posts
    4,239
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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


    Keep Excelling.

    Damon

    VBAexpert Excel Consulting
    LinkedIn Profile http://www.linkedin.com/pub/damon-ostrander/7/79/a93
    AllExperts Profile http://www.allexperts.com/ep/1059-30...-Ostrander.htm

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •