Clone A Workbook From XLSM To XLSX Format While Keeping XLSM Open
Many applications require the creation of a user-report workbook that doesn't contain VBA -- a clone of the macro-enabled workbook without the code. If the developer wants to keep the macro-enabled workbook open while creating this clone, then this example shows how to create a new XLSX workbook and copy worksheets from the macro-enabled workbook to the standard xlsx workbook.
Program Code
' ************************************************************
' Demonstrate Creating A Clone Workbook xlsx from xlsm
' And Crate a PDF Version Also
' ************************************************************
Option Explicit
Private Declare Function GetUserName Lib "advapi32.dll" Alias "GetUserNameA" (ByVal lpBuffer As String, nSize As Long) As Long
Public Sub SaveQuote()
Dim strCurrentDir As String
Dim strCustomerQuotesDir As String
Dim wkbSavedQuoteWorkbook As Workbook
Dim wkbSavedManufacturingSpecs As Workbook
Dim varQuoteFileName As Variant
Dim strPathToQuoteDirectory As String
Dim shpShape As Shape
Dim strApplicationFullPathAndName As String
Dim strPDFQuoteFileName As String
Dim strSearchForQuoteInLog As String
Dim C As Range
Dim lngGrandTotalRowInQuote As Long
Dim lngQuoteRowInLog As Long
Dim rngGrandTotalInQuote As Range
Dim rngGrandTotalInLog As Range
Dim lngLastRowOfManufacturingSpecs As Long
Dim strNameOfSpecsFile As String
Dim intLocationOfXLSX As Integer
If Len(strProductSheet) < 2 Or strGlobalsAreValid <> "Valid" Then
MsgBox ("Start Over - Globals Are Not Valid")
Exit Sub
End If
Application.ScreenUpdating = False
' *****************************************************************
' Update the Log Grand Total If The Quote Was Manually Altered
' *****************************************************************
' *****************************************************************
' Find The Grand Total
' *****************************************************************
Set C = wksCustomerQuote.UsedRange.Find("Grand Total Before Delivery Charges, Fees and Other Applicable Taxes:", LookIn:=xlValues)
If Not C Is Nothing Then
lngGrandTotalRowInQuote = C.Row
Else
lngGrandTotalRowInQuote = 0
End If
If lngGrandTotalRowInQuote = 0 Then
MsgBox ("Grand Total Row Not Located In Quote - Save Cancelled")
Application.ScreenUpdating = True
Exit Sub
End If
Set rngGrandTotalInQuote = Range(wksCustomerQuote.Cells(lngGrandTotalRowInQuote, 3), wksCustomerQuote.Cells(lngGrandTotalRowInQuote, 3))
' *****************************************************************
' Find The Quote Number In The Log
' *****************************************************************
strSearchForQuoteInLog = strQuoteNumberPrefixGbl & "-" & Format(lngQuoteNumberSuffixGbl, "0000")
Set C = wksQuoteJournal.UsedRange.Find(strSearchForQuoteInLog, LookIn:=xlValues)
If Not C Is Nothing Then
lngQuoteRowInLog = C.Row
Else
lngQuoteRowInLog = 0
End If
If lngQuoteRowInLog = 0 Then
MsgBox ("Quote Not Located in QuoteJournal Worksheet - Save Cancelled")
Application.ScreenUpdating = True
Exit Sub
End If
Set rngGrandTotalInLog = Range(wksQuoteJournal.Cells(lngQuoteRowInLog, 7), wksQuoteJournal.Cells(lngQuoteRowInLog, 7))
' *****************************************************************
' See If The Grand Total Was Manually Modified
' *****************************************************************
If Round(rngGrandTotalInQuote, 0) <> Round(rngGrandTotalInLog, 0) Then
rngGrandTotalInLog.Value = rngGrandTotalInQuote.Value
rngGrandTotalInLog.NumberFormat = "_($* #,##0_);_($* (#,##0);_($* ""-""_);_(@_)"
wksQuoteJournal.Cells(lngQuoteRowInLog, 17).Value = "Yes-Mod"
Else
wksQuoteJournal.Cells(lngQuoteRowInLog, 17).Value = "Yes"
End If
' *****************************************************************
' Get The Full Path To The Application To Break Links
' *****************************************************************
strApplicationFullPathAndName = wkbProductWorkbook.FullName
' *****************************************************************
' Validate That The User Has A Directory To Save Quotes
' *****************************************************************
strPathToQuoteDirectory = "C:\Users\" & UserNameWindows() & "\Documents\PetersonCustomerQuotes\"
If Not FolderExists(strPathToQuoteDirectory) Then
MkDir (strPathToQuoteDirectory)
End If
' *****************************************************************
' Save The Current Directory And Switch To The Quotes Directory
' *****************************************************************
strCurrentDir = CurDir()
ChDir (strPathToQuoteDirectory)
' *****************************************************************
' Create A New Workbook
' *****************************************************************
Set wkbSavedQuoteWorkbook = Workbooks.Add
' *****************************************************************
' Move The Completed Worksheets To The New Quote Workbook
' Hide the Not-Quote Worksheet
' Delete The Sheets Not Needed
' *****************************************************************
wksCustomerQuote.Copy Before:=wkbSavedQuoteWorkbook.Sheets(1)
wkbProductWorkbook.Sheets(strProductSheet).Copy Before:=wkbSavedQuoteWorkbook.Sheets(2)
' *****************************************************************
' Delete Any Buttons On the Customer Quote
' *****************************************************************
wkbSavedQuoteWorkbook.Sheets("CustomerQuote").Unprotect
wkbSavedQuoteWorkbook.Sheets(strProductSheet).Unprotect
For Each shpShape In wkbSavedQuoteWorkbook.Sheets("CustomerQuote").Shapes
If shpShape.Type = msoFormControl Then
shpShape.Delete
End If
Next shpShape
wkbSavedQuoteWorkbook.Sheets(strProductSheet).Visible = False
Application.DisplayAlerts = False
wkbSavedQuoteWorkbook.Sheets("Sheet1").Delete
wkbSavedQuoteWorkbook.Sheets("Sheet2").Delete
wkbSavedQuoteWorkbook.Sheets("Sheet3").Delete
Application.DisplayAlerts = True
SaveAValidFileName:
varQuoteFileName = Application.GetSaveAsFilename(strQuoteNumberPrefixGbl & "-" & Format(lngQuoteNumberSuffixGbl, "0000"), _
"Excel Files (*.xlsx), *.xlsx", , "Save Customer Quote")
If varQuoteFileName = False Then
MsgBox ("You Did Not Provide A Valid Name" & vbCrLf & _
"You Cannot Cancel This Operation" & vbCrLf & _
"Please Enter A New Name")
GoTo SaveAValidFileName
End If
If FileExists(CStr(varQuoteFileName)) Then
DeleteFile (CStr(varQuoteFileName))
End If
strPDFQuoteFileName = Replace(CStr(varQuoteFileName), ".xlsx", ".pdf")
' *****************************************************************
' Break Formula Links, Save And Close The File
' *****************************************************************
On Error GoTo ErrorInSave
wkbSavedQuoteWorkbook.BreakLink Name:=strApplicationFullPathAndName, Type:=xlExcelLinks
wkbSavedQuoteWorkbook.SaveAs Filename:=CStr(varQuoteFileName), FileFormat:=xlOpenXMLWorkbook
' *****************************************************************
' Save As PDF
' *****************************************************************
wkbSavedQuoteWorkbook.ExportAsFixedFormat Type:=xlTypePDF, Filename:= _
strPDFQuoteFileName, Quality:=xlQualityStandard, IncludeDocProperties:=True, _
IgnorePrintAreas:=False, OpenAfterPublish:=False
' *****************************************************************
' Close The New Workbook With No Additional Save
' *****************************************************************
wkbSavedQuoteWorkbook.Close SaveChanges:=False
' *****************************************************************
' If There is any data, then save the Manufacturing Specification
' *****************************************************************
On Error GoTo 0
lngLastRowOfManufacturingSpecs = wksManufacturingSpecs.Cells(Rows.Count, "B").End(xlUp).Row
If lngLastRowOfManufacturingSpecs > 3 Then
intLocationOfXLSX = InStr(1, varQuoteFileName, ".xlsx")
strNameOfSpecsFile = Left(varQuoteFileName, intLocationOfXLSX - 1) & "_Specs.xlsx"
' *****************************************************************
' Create A New Workbook
' *****************************************************************
Set wkbSavedManufacturingSpecs = Workbooks.Add
' *****************************************************************
' Move The Completed Manufacturing Specs To New Workbook
' Delete The Sheets Not Needed
' *****************************************************************
wksManufacturingSpecs.Copy Before:=wkbSavedManufacturingSpecs.Sheets(1)
Application.DisplayAlerts = False
wkbSavedManufacturingSpecs.Sheets("Sheet1").Delete
wkbSavedManufacturingSpecs.Sheets("Sheet2").Delete
wkbSavedManufacturingSpecs.Sheets("Sheet3").Delete
Application.DisplayAlerts = True
If FileExists(strNameOfSpecsFile) Then
DeleteFile (strNameOfSpecsFile)
End If
wkbSavedManufacturingSpecs.SaveAs Filename:=strNameOfSpecsFile, FileFormat:=xlOpenXMLWorkbook
' *****************************************************************
' Close The Specs Workbook With No Additional Changes
' *****************************************************************
wkbSavedManufacturingSpecs.Close SaveChanges:=False
End If
' *****************************************************************
' Save The Application With The Updates
' *****************************************************************
wkbProductWorkbook.Save
wksCustomerQuote.Unprotect
wksCustomerQuote.Protect
Application.ScreenUpdating = True
Exit Sub
ErrorInSave:
MsgBox ("You Must Specify A Diffent Name")
Resume SaveAValidFileName
End Sub
Public Function FolderExists(FolderPath As String) As Boolean
' *******************************************************************************************
' * THIS FUNCTION WILL TEST IF A FOLDER EXISTS *
' *******************************************************************************************
On Error GoTo err_In_Locate
' ***********************************************************
' * See If A Folder Exists *
' ***********************************************************
FolderExists = (Len(Dir(FolderPath, vbDirectory)) > 0)
mod_ExitFunction:
Exit Function
' ***************************************************
' * Error Correction Routines *
' ***************************************************
err_In_Locate:
FolderExists = False
Resume mod_ExitFunction
End Function
Public Function FileExists(FilePath As String) As Boolean
' *******************************************************************************************
' * THIS FUNCTION WILL TEST IF A FILE EXISTS *
' *******************************************************************************************
On Error GoTo err_In_Locate
' ***********************************************************
' * See If A File Exists - Provide The Full Path to the File
' ***********************************************************
FileExists = (Len(Dir(FilePath)) > 0)
mod_ExitFunction:
Exit Function
' ***************************************************
' * Error Correction Routines *
' ***************************************************
err_In_Locate:
FileExists = False
Resume mod_ExitFunction
End Function
Public Function DeleteFile(SourceFile As String) As Boolean
' *******************************************************************************************
' * DELETE A FILE *
' *******************************************************************************************
' *******************************************************************
' * (1) This function will delete a file *
' * (2) A full path to the file being deleted is recommended *
' * (3) If you omit the path, Access looks in the CurDir for the *
' * file to be deleted *
' *******************************************************************
On Error GoTo err_In_Delete
Kill SourceFile
DeleteFile = True
mod_ExitFunction:
Exit Function
' ***************************************************
' * File To Be Deleted Does Not Exist *
' ***************************************************
err_In_Delete:
DeleteFile = False
Resume mod_ExitFunction
End Function
Function UserNameWindows() As String
Dim lngLen As Long
Dim strBuffer As String
Const dhcMaxUserName = 255
strBuffer = Space(dhcMaxUserName)
lngLen = dhcMaxUserName
If CBool(GetUserName(strBuffer, lngLen)) Then
UserNameWindows = Left$(strBuffer, lngLen - 1)
Else
UserNameWindows = ""
End If
End Function