SaveAs in Excel 2007

Hi all

Creating a new workbook from the active sheet is not so easy anymore now we
have Excel 2007 with so many different file formats.

Below is a code example to copy the active sheet to a new workbook and save it.
This example is working in 97/2007.

If you run the code in Excel 2007 it will look at the FileFormat of the parent workbook and save the new file in that format.
Only if the parent workbook is an xlsm file and if there is no code in the new workbook it will save the new file as xlsx,
If the parent workbook is not an xlsx, xlsm, or xls then it will be saved as xlsb.

This are the main formats in Excel 2007 :

51 = xlOpenXMLWorkbook (without macro’s in 2007, xlsx)
52 = xlOpenXMLWorkbookMacroEnabled (with or without macro’s in 2007, xlsm)
50 = xlExcel12 (Excel Binary Workbook in 2007 with or without macro’s, xlsb)
56 = xlExcel8 (97-2003 format in Excel 2007, xls)

If you always want to save in a certain format you can replace this part of the macro

Select Case Sourcewb.FileFormat
    Case 51: FileExtStr = “.xlsx”: FileFormatNum = 51
    Case 52:
        If .HasVBProject Then
            FileExtStr = “.xlsm”: FileFormatNum = 52
        Else
            FileExtStr = “.xlsx”: FileFormatNum = 51
        End If
    Case 56: FileExtStr = “.xls”: FileFormatNum = 56
    Case Else: FileExtStr = “.xlsb”: FileFormatNum = 50
End Select

With one of the one liners from this list

FileExtStr = “.xlsb”: FileFormatNum = 50
FileExtStr = “.xlsx”: FileFormatNum = 51
FileExtStr = “.xlsm”: FileFormatNum = 52
FileExtStr = “.xls”: FileFormatNum = 56

Or maye you want to save the one sheet workbook to csv, txt ot prn.
(you can use this also if you run it in 97-2003)

FileExtStr = “.csv”: FileFormatNum = 6
FileExtStr = “.txt”: FileFormatNum = -4158
FileExtStr = “.prn”: FileFormatNum = 36

Sub Copy_ActiveSheet()
‘Working in Excel 97-2007
   Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim Sourcewb As Workbook
    Dim Destwb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
 
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
 
    Set Sourcewb = ActiveWorkbook
 
    ‘Copy the sheet to a new workbook
   ActiveSheet.Copy
    Set Destwb = ActiveWorkbook
 
    ‘Determine the Excel version and file extension/format
   With Destwb
        If Val(Application.Version) < 12 Then
            ‘You use Excel 97-2003
           FileExtStr = “.xls”: FileFormatNum = -4143
        Else
            ‘You use Excel 2007
           ‘We exit the sub when your answer is NO in the security dialog that you only
           ‘see  when you copy a sheet from a xlsm file with macro’s disabled.
           If Sourcewb.Name = .Name Then
                With Application
                    .ScreenUpdating = True
                    .EnableEvents = True
                End With
                MsgBox “Your answer is NO in the security dialog”
                Exit Sub
            Else
                Select Case Sourcewb.FileFormat
                Case 51: FileExtStr = “.xlsx”: FileFormatNum = 51
                Case 52:
                    If .HasVBProject Then
                        FileExtStr = “.xlsm”: FileFormatNum = 52
                    Else
                        FileExtStr = “.xlsx”: FileFormatNum = 51
                    End If
                Case 56: FileExtStr = “.xls”: FileFormatNum = 56
                Case Else: FileExtStr = “.xlsb”: FileFormatNum = 50
                End Select
            End If
        End If
    End With
 
    ‘    ‘Change all cells in the worksheet to values if you want
   ‘    With Destwb.Sheets(1).UsedRange
   ‘        .Cells.Copy
   ‘        .Cells.PasteSpecial xlPasteValues
   ‘        .Cells(1).Select
   ‘    End With
   ‘    Application.CutCopyMode = False

    ‘Save the new workbook and close it
   TempFilePath = Application.DefaultFilePath & “”
    TempFileName = “Part of “ & Sourcewb.Name & ” “ & Format(Now, “dd-mmm-yy h-mm-ss”)
 
    With Destwb
        .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
        .Close SaveChanges:=False
    End With
 
    MsgBox “You can find the new file in “ & Application.DefaultFilePath
 
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
End Sub

Also if you use code like GetSaveAsFilename then you must add a lot of code.

See the second example on this page
http://www.rondebruin.nl/saveas.htm


Posted in Uncategorized

3 thoughts on “SaveAs in Excel 2007

  1. Your post sparked a thought.

    I’ve always found it a quirky process to create a new workbook that has macros inside.
    I’ve tried two approaches:
    1. to start with a blank workbook, macros already included.
    2. insert the macros using the vba extensibility references.

    I wonder if 2007 now allows me to simply copy the macro file straight into the zip?
    – even if I need to tweak some xml files along the way, it could be another approach.

    I’ve deleted my 2007 beta so I cant tell.

    Rob


Posting code? Use <pre> tags for VBA and <code> tags for inline.

Leave a Reply

Your email address will not be published.