SaveCopyAs

werevollf

New Member
Joined
Sep 5, 2017
Messages
8
Hello everyone,

I am new with all macros and I`m trying to create macro which saves copy of workbook. But I cannot get my head going how to create one bit.. how to check the location before saving and if file name already exist message will come "file already exist please check name field" and would like to know instead of error message it will save file with add on like ...1.xls or ...copy1.xls, copy2.xls etc

this is code I`m using at the moment

Sub SaveAsB()

Dim FName As String
Dim FPath As String

FPath = '"C:\Test"
FName = Sheets("Sheet1").Range("A1").Text & Range("A2").Text
ActiveWorkbook.SaveCopyAs Filename:=FPath & "" & FName & ".xls"

End Sub

thanks :)
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Hi,
Welcome to forum.

Couple of ideas you can try

First idea hopefully should do what you ask & test if file in folder already exists. If so, it should add text “Copy” + index & test until there are no matches & then save the copy.

Code:
 Sub FileSaveCopy()    
    Dim FileName As String, FolderPath As String
    Dim FileExt As String, FullFilename As String
    Dim i As Integer
    
    FolderPath = "C:\Test\"
    
    With ThisWorkbook
    
        FileExt = Right$(.Name, Len(.Name) - InStrRev(.Name, ".") + 1)
        
        With .Worksheets("Sheet1")
            FileName = .Range("A1").Text & .Range("A2").Text
        End With
        
        i = 1
        If Len(FileName) = 0 Then Exit Sub
        Do
            FullFilename = FolderPath & FileName & FileExt
            If Not Dir(FullFilename) = vbNullString Then
                FileName = FileName & " Copy" & i
                i = i + 1
            Else
                Exit Do
            End If
        Loop
        .SaveCopyAs FileName:=FullFilename
    End With
    MsgBox FullFilename & Chr(10) & "File Copy Saved", "File Saved"
End Sub


An alternative approach would be just to add date & time to your file name in much same way when you make a backup

Code:
 Sub FileSaveCopy_V2()    
    Dim FileName As String, FolderPath As String
    Dim FileExt As String, FullFilename As String
    
    FolderPath = "C:\Test\"
    
    FileExt = IIf(Val(Application.Version) < 12, ".xls", ".xlsm")
    
    With ThisWorkbook
        FileExt = Right$(.Name, Len(.Name) - InStrRev(.Name, ".") + 1)
        With .Worksheets("Sheet1")
            FileName = .Range("A1").Text & .Range("A2").Text
        End With
        
        FullFilename = FolderPath & FileName & " " & Format(Now, "dd-mm-yyyy hh-mm-ss") & FileExt
        
        .SaveCopyAs FullFilename
    End With
    
    MsgBox FullFilename & Chr(10) & "File Copy Saved", "File Saved"
End Sub

You do not share what values you are storing in A1 & A2 of your worksheet but I assume they are legal names & do not include the file extension. If so, in both my examples, you need to exclude the extension from your range as when using FileCopy, you cannot change the file format to a different format e.g. xlsm to xlsx.

Both codes are untested & may need some adjustment to meet specific need but should give you something to work with.

Always make a backup of your workbook before testing new code.


Dave
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,250
Messages
6,171,036
Members
452,374
Latest member
keccles

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