Today’s author is Ron de Bruin , an Excel MVP. You can find more useful tips and links to Excel add-ins at his website: http://www.rondebruin.nl/
You see a lot of old SaveAs code that does not specify the FileFormat
parameter. In Excel versions before Excel 2007, code without this parameter
will not cause too many problems because Excel will use the current FileFormat
of the existing file — and the default FileFormat for new files is a normal workbook. But because there are so many new file formats in Excel 2007, you shouldn’t
use code that doesn’t specify the FileFormat parameter.
In Excel 2007, the SaveAs method requires you to provide both the FileFormat parameter and the correct file extension.
For example, in Excel 2007 this line of code will fail if the ActiveWorkbook is not an .xlsm file:
|
1 |
ActiveWorkbook.SaveAs <span class="str">"C:ron.xlsm"</span> |
But this code will always work:
|
1 2 |
ActiveWorkbook.SaveAs <span class="str">"C:ron.xlsm"</span>, fileformat:=52 <span class="rem">' 52 = xlOpenXMLWorkbookMacroEnabled = xlsm (workbook with macro's in 2007)</span> |
These are the main file 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)
Note: I always use the FileFormat numbers instead of the defined constants
in my code so that it will compile OK when I copy the code into an Excel
97-2003 workbook. (For example, Excel 97-2003 won’t know what the
xlOpenXMLWorkbookMacroEnabled constant is.)
Example
At the end of this section is a basic VBA code example for a macro named Copy_ActiveSheet_New_Workbook() that copies the ActiveSheet to a new Workbook and then saves it in a format that matches the file extension of the parent workbook.
Note: You can use this macro in Excel 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. However, if the parent workbook is an .xlsm file and there is no VBA code in the new workbook, the code will save the new file as an .xlsx file.
If the parent workbook is not an .xlsx, .xlsm or .xls file, then it will be saved as an .xlsb file.
If you always want to save in a certain format you can replace this part of the macro:
|
1 2 3 4 5 6 7 8 9 10 11 |
<span class="kwrd">Select</span> <span class="kwrd">Case</span> Sourcewb.FileFormat <span class="kwrd">Case</span> 51: FileExtStr = <span class="str">".xlsx"</span>: FileFormatNum = 51 <span class="kwrd">Case</span> 52: <span class="kwrd">If</span> .HasVBProject <span class="kwrd">Then</span> FileExtStr = <span class="str">".xlsm"</span>: FileFormatNum = 52 <span class="kwrd">Else</span> FileExtStr = <span class="str">".xlsx"</span>: FileFormatNum = 51 <span class="kwrd">End</span> <span class="kwrd">If</span> <span class="kwrd">Case</span> 56: FileExtStr = <span class="str">".xls"</span>: FileFormatNum = 56 <span class="kwrd">Case</span> <span class="kwrd">Else</span>: FileExtStr = <span class="str">".xlsb"</span>: FileFormatNum = 50 <span class="kwrd">End</span> Select |
|
1 |
With the single line of code from this list for the format you want to use: |
|
1 2 3 4 |
FileExtStr = <span class="str">".xlsb"</span>: FileFormatNum = 50 FileExtStr = <span class="str">".xlsx"</span>: FileFormatNum = 51 FileExtStr = <span class="str">".xlsm"</span>: FileFormatNum = 52 FileExtStr = <span class="str">".xls"</span>: FileFormatNum = 56 |
Or maybe you want to save the one sheet workbook to .csv, .txt, or .prn. (you can use this also if you run the macro in Excel 97-2003)
|
1 2 3 |
FileExtStr = <span class="str">".csv"</span>: FileFormatNum = 6 FileExtStr = <span class="str">".txt"</span>: FileFormatNum = -4158 FileExtStr = <span class="str">".prn"</span>: FileFormatNum = 36 |
Here’s the full code example.
|
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 |
<span class="kwrd">Sub</span> Copy_ActiveSheet_New_Workbook() <span class="rem">'Working in Excel 97-2007</span> <span class="kwrd">Dim</span> FileExtStr <span class="kwrd">As</span> <span class="kwrd">String</span> <span class="kwrd">Dim</span> FileFormatNum <span class="kwrd">As</span> <span class="kwrd">Long</span> <span class="kwrd">Dim</span> Sourcewb <span class="kwrd">As</span> Workbook <span class="kwrd">Dim</span> Destwb <span class="kwrd">As</span> Workbook <span class="kwrd">Dim</span> TempFilePath <span class="kwrd">As</span> <span class="kwrd">String</span> <span class="kwrd">Dim</span> TempFileName <span class="kwrd">As</span> <span class="kwrd">String</span> <span class="kwrd">With</span> Application .ScreenUpdating = <span class="kwrd">False</span> .EnableEvents = <span class="kwrd">False</span> <span class="kwrd">End</span> <span class="kwrd">With</span> <span class="kwrd">Set</span> Sourcewb = ActiveWorkbook <span class="rem">'Copy the sheet to a new workbook</span> ActiveSheet.Copy <span class="kwrd">Set</span> Destwb = ActiveWorkbook <span class="rem">'Determine the Excel version and file extension/format</span> <span class="kwrd">With</span> Destwb <span class="kwrd">If</span> Val(Application.Version) < 12 <span class="kwrd">Then</span> <span class="rem">'You use Excel 97-2003</span> FileExtStr = <span class="str">".xls"</span>: FileFormatNum = -4143 <span class="kwrd">Else</span> <span class="rem">'You use Excel 2007</span> <span class="rem">'We exit the sub when your answer is NO in the security dialog that you</span> <span class="rem">'only see when you copy a sheet from a xlsm file with macro's disabled.</span> <span class="kwrd">If</span> Sourcewb.Name = .Name <span class="kwrd">Then</span> <span class="kwrd">With</span> Application .ScreenUpdating = <span class="kwrd">True</span> .EnableEvents = <span class="kwrd">True</span> <span class="kwrd">End</span> <span class="kwrd">With</span> MsgBox <span class="str">"Your answer is NO in the security dialog"</span> <span class="kwrd">Exit</span> <span class="kwrd">Sub</span> <span class="kwrd">Else</span> <span class="kwrd">Select</span> <span class="kwrd">Case</span> Sourcewb.FileFormat <span class="kwrd">Case</span> 51: FileExtStr = <span class="str">".xlsx"</span>: FileFormatNum = 51 <span class="kwrd">Case</span> 52: <span class="kwrd">If</span> .HasVBProject <span class="kwrd">Then</span> FileExtStr = <span class="str">".xlsm"</span>: FileFormatNum = 52 <span class="kwrd">Else</span> FileExtStr = <span class="str">".xlsx"</span>: FileFormatNum = 51 <span class="kwrd">End</span> <span class="kwrd">If</span> <span class="kwrd">Case</span> 56: FileExtStr = <span class="str">".xls"</span>: FileFormatNum = 56 <span class="kwrd">Case</span> <span class="kwrd">Else</span>: FileExtStr = <span class="str">".xlsb"</span>: FileFormatNum = 50 <span class="kwrd">End</span> <span class="kwrd">Select</span> <span class="kwrd">End</span> <span class="kwrd">If</span> <span class="kwrd">End</span> <span class="kwrd">If</span> <span class="kwrd">End</span> <span class="kwrd">With</span> <span class="rem">' 'If you want to change all cells in the worksheet to values, uncomment these lines.</span> <span class="rem">' With Destwb.Sheets(1).UsedRange</span> <span class="rem">' .Cells.Copy</span> <span class="rem">' .Cells.PasteSpecial xlPasteValues</span> <span class="rem">' .Cells(1).Select</span> <span class="rem">' End With</span> <span class="rem">' Application.CutCopyMode = False</span> <span class="rem">'Save the new workbook and close it</span> TempFilePath = Application.DefaultFilePath & <span class="str">""</span> TempFileName = <span class="str">"Part of "</span> & Sourcewb.Name & <span class="str">" "</span> & Format(Now, <span class="str">"yyyy-mm-dd hh-mm-ss"</span>) <span class="kwrd">With</span> Destwb .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum .Close SaveChanges:=<span class="kwrd">False</span> <span class="kwrd">End</span> <span class="kwrd">With</span> MsgBox <span class="str">"You can find the new file in "</span> & TempFilePath <span class="kwrd">With</span> Application .ScreenUpdating = <span class="kwrd">True</span> .EnableEvents = <span class="kwrd">True</span> <span class="kwrd">End</span> <span class="kwrd">With</span> <span class="kwrd">End</span> <span class="kwrd">Sub</span> |

