Adapt this code to save to Excel rather than PDF?

SlinkRN

Well-known Member
Joined
Oct 29, 2002
Messages
715
I found this really cool code from the Contextures site to save one sheet to a PDF file and it works wonderfully!!! Unfortunately, I need to save as an Excel file rather than PDF. I've tried adjusting it and I can kind of get it to work but not quite. Can anyone tell me what to adjust to get this code to work for an Excel output rather than PDF?
VBA Code:
Sub PDFActiveSheet()
'www.contextures.com
'for Excel 2010 and later
Dim wsA As Worksheet
Dim wbA As Workbook
Dim strTime As String
Dim strName As String
Dim strPath As String
Dim strFile As String
Dim strPathFile As String
Dim myFile As Variant
On Error GoTo errHandler

Set wbA = ActiveWorkbook
Set wsA = ActiveSheet
strTime = Format(Now(), "yyyymmdd\_hhmm")

'get active workbook folder, if saved
strPath = wbA.Path
If strPath = "" Then
strPath = Application.DefaultFilePath
End If
strPath = strPath & "\"

'replace spaces and periods in sheet name
strName = Replace(wsA.Name, " ", "")
strName = Replace(strName, ".", "_")

'create default name for savng file
strFile = strName & "_" & strTime & ".pdf"
strPathFile = strPath & strFile

'use can enter name and
' select folder for file
myFile = Application.GetSaveAsFilename _
(InitialFileName:=strPathFile, _
FileFilter:="PDF Files (*.pdf), *.pdf", _
Title:="Select Folder and FileName to save")

'export to PDF if a folder was selected
If myFile <> "False" Then
wsA.ExportAsFixedFormat _
Type:=xlTypePDF, _
Filename:=myFile, _
Quality:=xlQualityStandard, _
IncludeDocProperties:=True, _
IgnorePrintAreas:=False, _
OpenAfterPublish:=False
'confirmation message with file info
MsgBox "PDF file has been created: " _
& vbCrLf _
& myFile
End If

exitHandler:
Exit Sub
errHandler:
MsgBox "Could not create PDF file"
Resume exitHandler
End Sub
VBA Code:
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
I have tested this and it seems to do the job. If you are posting code then please use the vba icon next to the smiley as it helps reading the code.

VBA Code:
Sub PDFActiveSheet()
'www.contextures.com
'for Excel 2010 and later
Dim wsA As Worksheet
Dim wbA As Workbook
Dim strTime As String
Dim strName As String
Dim strPath As String
Dim strFile As String
Dim strPathFile As String
Dim myFile As Variant
On Error GoTo errHandler

Set wbA = ActiveWorkbook
Set wsA = ActiveSheet
strTime = Format(Now(), "yyyymmdd\_hhmm")

'get active workbook folder, if saved
strPath = wbA.Path
If strPath = "" Then
strPath = Application.DefaultFilePath
End If
strPath = strPath & "\"

'replace spaces and periods in sheet name
strName = Replace(wsA.Name, " ", "")
strName = Replace(strName, ".", "_")

'create default name for savng file
strFile = strName & "_" & strTime & ".xlsx"
strPathFile = strPath & strFile

'use can enter name and
' select folder for file
myFile = Application.GetSaveAsFilename _
(InitialFileName:=strPathFile, _
FileFilter:="Excel Files (*.xlsx), *.xlsx", _
Title:="Select Folder and FileName to save")

'export to Excel if a folder was selected
If myFile <> "False" Then
wsA.SaveAs strPathFile

'confirmation message with file info
MsgBox "Workbook file has been created: " _
& vbCrLf _
& myFile
End If

exitHandler:
Exit Sub
errHandler:
MsgBox "Could not create Workbook file"
Resume exitHandler
End Sub
 
Upvote 0
@Trevor G , it gives me a "Could not create Workbook file"
@SlinkRN , you might give this a try:
VBA Code:
Sub ActiveSheetToWorkbook()

    Dim oWs         As Worksheet
    Dim sTime       As String
    Dim sName       As String
    Dim sPath       As String
    Dim sFile       As String
    Dim sPathFile   As String
    Dim vDlgResult  As Variant
    
    Set oWs = ActiveSheet   ' <<< change accordingly
    
    sTime = Format(Now(), "yyyymmdd\_hhmm")
    ' get active workbook folder, if saved
    sPath = oWs.Parent.Path & "\"
    If Len(sPath) = 1 Then
        sPath = Application.DefaultFilePath & "\"
    End If
    ' replace spaces and periods in sheet name
    sName = Replace(oWs.Name, " ", "")
    sName = Replace(sName, ".", "_")
    ' create default name for savng file
    sFile = sName & "_" & sTime & ".xlsx"
    sPathFile = sPath & sFile
    ' select folder and/or change file name
    vDlgResult = Application.GetSaveAsFilename(InitialFileName:=sPathFile, _
                                               FileFilter:="Excel Workbook (*.xlsx), *.xlsx", _
                                               Title:="Save Worksheet As Workbook:")
    ' save worksheet as workbook
    If vDlgResult <> "False" Then
        Application.ScreenUpdating = False
        oWs.Copy
        With ActiveWorkbook
             .SaveAs Filename:=vDlgResult
             .Close SaveChanges:=False
        End With
        Application.ScreenUpdating = True
        MsgBox "File [" & sPathFile & "] successfully created.", vbInformation, oWs.Parent.Name
    Else
        MsgBox "Canceled by user", vbExclamation, oWs.Parent.Name
    End If
    Set oWs = Nothing
End Sub
 
Upvote 0
I also got an error with your code Trevor, not sure why since it seemed correct. GWteB, your code does the trick! Thank you SO much! Slink
 
Upvote 0
You're welcome and thanks for letting me know.
 
Upvote 0
Good to read you have a solution.
 
Upvote 0

Forum statistics

Threads
1,214,590
Messages
6,120,423
Members
448,961
Latest member
nzskater

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