PDA

View Full Version : Saving file in specific location



msussams
02-07-2021, 06:08 AM
Sub saveandsnd()Dim xSht As Worksheet
Dim xFileDlg As FileDialog
Dim xFolder As String
Dim xYesorNo As Integer
Dim xOutlookObj As Object
Dim xEmailObj As Object
Dim xUsedRng As Range



Set xSht = ActiveSheet
Set xFileDlg = Application.FileDialog(msoFileDialogFolderPicker)

If xFileDlg.Show = True Then
xFolder = xFileDlg.SelectedItems(1)
Else
MsgBox "You must specify a folder to save the PDF into." & vbCrLf & vbCrLf & "Press OK to exit this macro.", vbCritical, "Must Specify Destination Folder"
Exit Sub
End If
xFolder = xFolder + "\" + xSht.Name + " " + Format(DateTime.Now, "dd-MM-yyyy") + ".pdf"

'Check if file already exist
If Len(Dir(xFolder)) > 0 Then
xYesorNo = MsgBox(xFolder & " already exists." & vbCrLf & vbCrLf & "Do you want to overwrite it?", _
vbYesNo + vbQuestion, "File Exists")
On Error Resume Next
If xYesorNo = vbYes Then
Kill xFolder
Else
MsgBox "if you don't overwrite the existing PDF, I can't continue." _
& vbCrLf & vbCrLf & "Press OK to exit this macro.", vbCritical, "Exiting Macro"
Exit Sub
End If
If Err.Number <> 0 Then
MsgBox "Unable to delete existing file. Please make sure the file is not open or write protected." _
& vbCrLf & vbCrLf & "Press OK to exit this macro.", vbCritical, "Unable to Delete File"
Exit Sub
End If
End If

Set xUsedRng = xSht.UsedRange
If Application.WorksheetFunction.CountA(xUsedRng.Cells) <> 0 Then
'Save as PDF file
xSht.ExportAsFixedFormat Type:=xlTypePDF, Filename:=xFolder, Quality:=xlQualityStandard

'Create Outlook email
Set xOutlookObj = CreateObject("Outlook.Application")
Set xEmailObj = xOutlookObj.CreateItem(0)
With xEmailObj
.Display
.To = "emailhere"
.CC = "emailhere"
.Subject = xSht.Name + " " + "to be checked -" + " " + Format(DateTime.Now, "dd/MM/yyyy")
.Attachments.Add xFolder
.body = "Hi All," & vbNewLine & "Please find attached Tins that I need checking on CCF. I Hope it is self explanatory." & vbNewLine & "" & vbNewLine & "Hope you have a good shift." & vbNewLine & "" & vbNewLine & "Many Thanks,"
If DisplayEmail = False Then
'.Send
End If
End With
Else
MsgBox "The active worksheet cannot be blank"
Exit Sub
End If
End Sub




I have this macro which works, but doesn't save to a specific folder...
I've tried to use help to change/add things but doesn't seem to change the results
Do any of you know how to adapt this to save to a specific location?
thanks for your time....

gmayor
02-07-2021, 06:44 AM
Your macro saves the PDF to the folder XFolder that you choose from the dialog box. Where did you want it to be saved?
If you don't need to keep a separate copy of the PDF, and eliminate the need to check if it exists, because it never should, you could save it to the desktop then delete it after attaching it to the message e.g.

Sub saveandsnd()
'Graham Mayor - https://www.gmayor.com - Last updated - 07 Feb 2021
Dim xSht As Worksheet
Dim xFolder As String
Dim xOutlookObj As Object
Dim xEmailObj As Object
Dim xUsedRng As Range

Set xSht = ActiveSheet
xFolder = Environ("USERPROFILE") & "\Desktop\"

xFolder = xFolder & xSht.Name & " " & Format(DateTime.Now, "dd-MM-yyyy") & ".pdf"

Set xUsedRng = xSht.UsedRange
If Application.WorksheetFunction.CountA(xUsedRng.Cells) <> 0 Then
'Save as PDF file
xSht.ExportAsFixedFormat Type:=xlTypePDF, FileName:=xFolder, Quality:=xlQualityStandard
'Create Outlook email
Set xOutlookObj = CreateObject("Outlook.Application")
Set xEmailObj = xOutlookObj.CreateItem(0)
With xEmailObj
.Display
.To = "emailhere"
.CC = "emailhere"
.Subject = xSht.Name & " to be checked - " & Format(DateTime.Now, "dd/MM/yyyy")
.Attachments.Add xFolder
.body = "Hi All," & vbNewLine & "Please find attached Tins that I need checking on CCF. I Hope it is self explanatory." & _
vbNewLine & "" & vbNewLine & "Hope you have a good shift." & vbNewLine & "" & vbNewLine & "Many Thanks,"
'.Send
End With
End If
Kill xFolder 'delete the pdf
Set xOutlookObj = Nothing
Set xUsedRng = Nothing
Set xEmailObj = Nothing
Exit Sub
End Sub

snb
02-07-2021, 07:43 AM
Sufficient code:


Sub M_snb()
With Application.FileDialog(4)
If .Show Then If Dir(.SelectedItems(1) & "\Example.pdf") = "" Then ThisWorkbook.ExportAsFixedFormat 0, .SelectedItems(1) & "\Example.pdf"
End With
End Sub