Macro to open document from a folder

tonywatsonhelp

Well-known Member
Joined
Feb 24, 2014
Messages
3,194
Office Version
  1. 365
  2. 2019
  3. 2016
Platform
  1. Windows
Hi Everyone,

So i need a macro that can open a document from a folder in excel,
now the problem is i don't know what the full name of the document so i was wondering if i could get excel to open the version that was saved last?

So heres my idea,

In D10 i have the folder location
in D12 i have what the document starts with (for example "Data records")

the macro when run first checks the folder exists, if not message box "Folder missing"

then checks if there is at least one document call "Data Records" that is a XLSM doc

if there's only one, open this document,
if there are more than one, open the one with the newest saved date? (if this is not possible then dont open anything just a messagebox say "more than one" will do.

thanks

Tony
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Paste this code into a module, and it will open ANY file in its native application.
usage: OpenNativeApp range("a2").value

OpenNativeApp "c:\folder\file.pdf"
will open it in acrobat

OpenNativeApp "c:\folder\"
will open the folder

OpenNativeApp "www.google.com"
will open web browser.

Code:
Private Declare Function ShellExecute Lib "shell32.dll" Alias "ShellExecuteA" (ByVal hwnd As Long, ByVal lpszOp As String, ByVal lpszFile As String, ByVal lpszParams As String, ByVal lpszDir As String, ByVal FsShowCmd As Long) As Long
Private Declare Function GetDesktopWindow Lib "user32" () As Long
Const SW_SHOWNORMAL = 1
Const SE_ERR_FNF = 2&
Const SE_ERR_PNF = 3&
Const SE_ERR_ACCESSDENIED = 5&
Const SE_ERR_OOM = 8&
Const SE_ERR_DLLNOTFOUND = 32&
Const SE_ERR_SHARE = 26&
Const SE_ERR_ASSOCINCOMPLETE = 27&
Const SE_ERR_DDETIMEOUT = 28&
Const SE_ERR_DDEFAIL = 29&
Const SE_ERR_DDEBUSY = 30&
Const SE_ERR_NOASSOC = 31&
Const ERROR_BAD_FORMAT = 11&

Public Sub OpenNativeApp(ByVal psDocName As String)
Dim r As Long, msg As String
r = StartDoc(psDocName)
If r <= 32 Then
'There was an error
Select Case r
Case SE_ERR_FNF
msg = "File not found"
Case SE_ERR_PNF
msg = "Path not found"
Case SE_ERR_ACCESSDENIED
msg = "Access denied"
Case SE_ERR_OOM
msg = "Out of memory"
Case SE_ERR_DLLNOTFOUND
msg = "DLL not found"
Case SE_ERR_SHARE
msg = "A sharing violation occurred"
Case SE_ERR_ASSOCINCOMPLETE
msg = "Incomplete or invalid file association"
Case SE_ERR_DDETIMEOUT
msg = "DDE Time out"
Case SE_ERR_DDEFAIL
msg = "DDE transaction failed"
Case SE_ERR_DDEBUSY
msg = "DDE busy"
Case SE_ERR_NOASSOC
msg = "No association for file extension"
Case ERROR_BAD_FORMAT
msg = "Invalid EXE file or error in EXE image"
Case Else
msg = "Unknown error"
End Select
' MsgBox msg
End If
End Sub
 
Upvote 0
Try:
VBA Code:
Sub OpenLatestVersion()
    Application.ScreenUpdating = False
    Dim MyPath As String, MyFile As String, LatestFile As String, LatestDate As Date, dDT As Date
    Dim foldName As String, foldExists As String
    MyPath = Range("D10")
    foldExists = Dir(MyPath, vbDirectory)
    If foldExists <> "" Then
        MyFile = Dir(MyPath & "*.xlsm", vbNormal)
        If InStr(MyFile, Range("D12")) <> 0 Then
            Do While Len(MyFile) > 0
                dDT = FileDateTime(MyPath & MyFile)
                If dDT > LatestDate Then
                    LatestFile = MyFile
                    LatestDate = dDT
                End If
                MyFile = Dir
            Loop
            Workbooks.Open MyPath & LatestFile
        Else
            MsgBox ("No files which start with '" & Range("D12") & "' exist.")
        End If
    Else
        MsgBox ("Folder does not exist.")
    End If
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,214,956
Messages
6,122,465
Members
449,085
Latest member
ExcelError

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