VBA command to open PDF

Adnan_razaq

New Member
Joined
Nov 14, 2019
Messages
11
Hi All,

my first post here :)

I am trying to create an interface to select and open PDF reports from Excel.

Currently I have got 4 drop down boxes where users can select which report they would like to see.

Currently the options are

drop down box 1 : Europe, America and Pacific
drop down box 2 : Red, Blue and Green
drop down box 3: months of year and
drop down box 4: years from 2015-19

once a users selects the above options, I would like to create a button based on the user choices to open a PDF report in a shared folder

for instance, if a user selects Europe, Red, and Jun 2019 the appropriate report will open

Many Thanks in advance
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Welcome to MrExcel forums.

You haven't said exactly how the PDF file name should be constructed from the 4 drop down values, but see if this macro works for you. The 4 drop downs are Form Control Combo Boxes placed on a worksheet and with their default names: "Drop Down 1", "Drop Down 2", etc. Edit the code to change the PDFsfolder string, which is the folder containing the PDF files. Assign the following macro to the command button on the worksheet:

Code:
Option Explicit

[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=If]#If[/URL]  VBA7 Then
    Private Declare PtrSafe Function FindExecutable Lib "shell32.dll" Alias "FindExecutableA" _
       (ByVal lpFile As String, ByVal lpDirectory As String, ByVal lpResult As String) As Long
[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=Else]#Else[/URL] 
    Private Declare Function FindExecutable Lib "shell32.dll" Alias "FindExecutableA" _
       (ByVal lpFile As String, ByVal lpDirectory As String, ByVal lpResult As String) As Long
[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=End]#End[/URL]  If


Public Sub Open_PDF()

    Dim DropDowns(1 To 4) As DropDown
    Dim PDFsfolder As String
    Dim PDFfileName As String
    Dim PDFexe As String
    
    PDFsfolder = "C:\path\to\PDFs"               'folder containing PDF files
    If Right(PDFsfolder, 1) <> "" Then PDFsfolder = PDFsfolder & ""
    
    Set DropDowns(1) = ActiveSheet.Shapes("Drop Down 1").OLEFormat.Object
    Set DropDowns(2) = ActiveSheet.Shapes("Drop Down 2").OLEFormat.Object
    Set DropDowns(3) = ActiveSheet.Shapes("Drop Down 3").OLEFormat.Object
    Set DropDowns(4) = ActiveSheet.Shapes("Drop Down 4").OLEFormat.Object
    
    If DropDowns(1).ListIndex + DropDowns(2).ListIndex + DropDowns(3).ListIndex + DropDowns(4).ListIndex >= 4 Then

        PDFfileName = Range(DropDowns(1).ListFillRange).Item(DropDowns(1).ListIndex).Value & " " & _
                      Range(DropDowns(2).ListFillRange).Item(DropDowns(2).ListIndex).Value & " " & _
                      Range(DropDowns(3).ListFillRange).Item(DropDowns(3).ListIndex).Value & " " & _
                      Range(DropDowns(4).ListFillRange).Item(DropDowns(4).ListIndex).Value & ".pdf"
                      
        If Dir(PDFsfolder & PDFfileName) <> vbNullString Then
            PDFexe = Get_ExePath(PDFsfolder & PDFfileName)
            Shell PDFexe & " " & Chr(34) & PDFsfolder & PDFfileName & Chr(34), vbNormalFocus
        Else
            MsgBox PDFsfolder & PDFfileName & " not found", vbExclamation
        End If
    End If
    
End Sub


Private Function Get_ExePath(lpFile As String) As String
    Dim lpDirectory As String, sExePath As String, rc As Long
    lpDirectory = ""
    sExePath = Space(255)
    rc = FindExecutable(lpFile, lpDirectory, sExePath)
    Get_ExePath = Left$(sExePath, InStr(sExePath, Chr$(0)) - 1)
End Function
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,155
Members
453,021
Latest member
Justyna P

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