last modified date of imported text file with VBA

Dark0Prince

Active Member
Joined
Feb 17, 2016
Messages
433
I'm not sure how to do this, but I have an imported file from text, and I need to make sure that the last modified date isn't older then 5days and if it is I need some text box that says "file too old" or something like that.
 
Code:
Sub PROG_05565()
'
' PROG_05565 Macro
'

'
    Range("A13").Select
    Application.CutCopyMode = False
    With ActiveSheet.QueryTables.Add(Connection:="TEXT;C:\abq\PROG_05565.TXT", _
        Destination:=Range("$A$13"))
        .Name = "PROG_5565"
        .FieldNames = True
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = True
        .RefreshOnFileOpen = False
        .RefreshStyle = xlInsertDeleteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .TextFilePromptOnRefresh = False
        .TextFilePlatform = 437
        .TextFileStartRow = 1
        .TextFileParseType = xlFixedWidth
        .TextFileTextQualifier = xlTextQualifierDoubleQuote
        .TextFileConsecutiveDelimiter = False
        .TextFileTabDelimiter = True
        .TextFileSemicolonDelimiter = False
        .TextFileCommaDelimiter = False
        .TextFileSpaceDelimiter = False
        .TextFileColumnDataTypes = Array(2, 1, 1, 1, 1, 1, 1)
        .TextFileFixedColumnWidths = Array(36, 8, 9, 11, 9, 17)
        .TextFileTrailingMinusNumbers = True
        .Refresh BackgroundQuery:=False
    End With
    Range("F:F,E:E,C:C").Select
    Range("C1").Activate
    Selection.NumberFormat = "$#,##0.00_);[Red]($#,##0.00)"
    Columns("D:D").Select
    Selection.NumberFormat = "m/d/yyyy"
    Columns("A:G").Select
    Range("G1").Activate
    Columns("A:G").EntireColumn.AutoFit
    Range("A12").Select
End Sub
 
Upvote 0

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
I haven't been able to test this, but i wrote this and it looks like what i want just don't know if I wrote it wrong i'll have to try on tuesday.
Code:
Dim lastMod As String

lastMod = FileDateTime( "C:\abq\PROG_05565.txt" )
If cell.A1 < cDate(lastMod) Then
MsgBox(lastMod)
End If
Next
 
Upvote 0
I haven't been able to test this, but i wrote this and it looks like what i want just don't know if I wrote it wrong i'll have to try on tuesday.
Rich (BB code):
Dim lastMod As String

lastMod = FileDateTime( "C:\abq\PROG_05565.txt" )
If cell.A1 < cDate(lastMod) Then
MsgBox(lastMod)
End If
Next
What is what I highlighted in red supposed to be? Did you perhaps mean Cells.Range("A1")? If so, you could just write Range("A1") and it would be better if you specified the Value property and wrote it Range("A1").Value.
 
Upvote 0
What is what I highlighted in red supposed to be? Did you perhaps mean [COLOR=[URL="https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=000"]#000[/URL] 0FF]Cells.Range("A1")[/COLOR]? If so, you could just write [COLOR=[URL="https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=000"]#000[/URL] 0FF]Range("A1")[/COLOR] and it would be better if you specified the Value property and wrote it [COLOR=[URL="https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=000"]#000[/URL] 0FF]Range("A1").Value[/COLOR].

It is supposed to be a date that I write in there to compare to last modified date. here is current code that runs but no msg box comes up.
Code:
Sub PROG_01940()
'
' PROG_01940 Macro
'
Dim lastMod As String

lastMod = FileDateTime("C:\abq\PROG_01940.txt")
If Range("A1").Value < CDate(lastMod) Then MsgBox (lastMod)



'
    With ActiveSheet.QueryTables.Add(Connection:="TEXT;C:\abq\PROG_01940.TXT", _
        Destination:=Range("$A$13"))
        .Name = "PROG_1940"
        .FieldNames = True
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = True
        .RefreshOnFileOpen = False
        .RefreshStyle = xlInsertDeleteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .TextFilePromptOnRefresh = False
        .TextFilePlatform = 437
        .TextFileStartRow = 1
        .TextFileParseType = xlDelimited
        .TextFileTextQualifier = xlTextQualifierDoubleQuote
        .TextFileConsecutiveDelimiter = False
        .TextFileTabDelimiter = True
        .TextFileSemicolonDelimiter = False
        .TextFileCommaDelimiter = True
        .TextFileSpaceDelimiter = False
        .TextFileColumnDataTypes = Array(2, 3, 1, 3, 1, 1, 1)
        .TextFileTrailingMinusNumbers = True
        .Refresh BackgroundQuery:=False
    End With
    Range("E:F,C:C").Select
    Range("C1").Activate
    Selection.NumberFormat = "$#,##0.00_);[Red]($#,##0.00)"
    Range("D:D,B:B").Select
    Range("B1").Activate
    Selection.NumberFormat = "m/d/yyyy"
    Columns("A:F").Select
    Range("F3").Activate
    Columns("A:F").EntireColumn.AutoFit
    Range("A12").Select
End Sub
 
Last edited:
Upvote 0
It is supposed to be a date that I write in there to compare to last modified date. here is current code that runs but no msg box comes up.
I guess the question is... exactly what do you have in cell A1 (is it a formula or constant, what is its value and what is the cell's format)?
 
Upvote 0
I guess the question is... exactly what do you have in cell A1 (is it a formula or constant, what is its value and what is the cell's format)?

In Cell A1 I have today's date. 10/10/2017 It's manually put in there before the import. It's in short date format and it is now working and coming up with the msg box. The new problem is that I don't know how to change my code to say lastmod-5days because I only want the pop up or warning box to come up if it is 5 days or more older then today's date.
 
Upvote 0
I decided to go with this type msg box, but don't know how to exit sub when they answer no.

Code:
Dim lastMod As String


lastMod = FileDateTime("C:\abq\PROG_01940.txt")
If CDate(lastMod) < Date - 5 Then MsgBox "Are you sure you want to Import this file with a last modified date of" & (lastMod), vbYesNo + vbExclamation
 
Upvote 0
Code:
 If answer = vbNo Then: Exit Sub
I added this to my code and it works great!

When I put this on another sub I can a runtime error on it.

Rich (BB code):
Dim lastMod As String
Dim answer As String

lastMod = FileDateTime("C:\abq\PROG_06055.txt")
If CDate(lastMod) < Date - 9 Then answer = MsgBox("Are you sure you want to Import this file? With a last modified date of: " & (lastMod), vbYesNo + vbExclamation)
If answer = vbNo Then: Exit Sub

Where it's bold I have a run-time error 13: type mismatch
 
Upvote 0
Code:
 If answer = vbNo Then: Exit Sub
I added this to my code and it works great!

When I put this on another sub I can a runtime error on it.

Rich (BB code):
Dim lastMod As String
Dim answer As String

lastMod = FileDateTime("C:\abq\PROG_06055.txt")
If CDate(lastMod) < Date - 9 Then answer = MsgBox("Are you sure you want to Import this file? With a last modified date of: " & (lastMod), vbYesNo + vbExclamation)
If answer = vbNo Then: Exit Sub

Where it's bold I have a run-time error 13: type mismatch
You are executing the code line whether the MsgBox was displayed or not... when the MsgBox has not been displayed, the answer variable has no value. You need to tie the tow together. Try it this way (note I took your single line If..Then statement and converted it to block form so that I could include the testing of answer in the same block with the MsgBox which assigns a value to it)...
Rich (BB code):
Dim lastMod As String
Dim answer As String

lastMod = FileDateTime("C:\abq\PROG_06055.txt")
If CDate(lastMod) < Date - 9 Then
  answer = MsgBox("Are you sure you want to Import this file? With a last modified date of: " & (lastMod), vbYesNo + vbExclamation)
  If answer = vbNo Then: Exit Sub
End If
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,825
Messages
6,181,191
Members
453,021
Latest member
pingpong7117

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