VB creates workbooks for each sheet, but incorrect folder

AngelK

New Member
Joined
Aug 4, 2016
Messages
34
I have a workbook that has 20 sheets. My goal is to save each sheet to it's own workbook, in the same folder as my original workbook. The code below is in my Personal.xlsb, and it creates a workbook just for my vb book (although I have the 20-sheet workbook open), and saves it in my xlStart file. Not what I need.
If I copy the code to my ThisWorkbook, and hard code the file path, it works great (creates 20 workbooks in the right folder). I need to have this code create the folder and copy the workbooks where the original file is saved, not my personal.xlsb. Help!

Code:
Sub Copy_Every_Sheet_To_New_Workbook()
 
    Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim Sourcewb As Workbook
    Dim Destwb As Workbook
    Dim sh As Worksheet
    Dim DateString As String
    Dim FolderName As String
 
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
        .Calculation = xlCalculationManual
    End With
 
    'Copy every sheet from the workbook with this macro
    Set Sourcewb = ThisWorkbook
 
    'Create new folder to save the new files in
    DateString = Format(Now, "yyyy-mm-dd hh-mm-ss")
    FolderName = Sourcewb.Path & "" & Sourcewb.name & " " & DateString
    MkDir FolderName
 
    'Copy every visible sheet to a new workbook
    For Each sh In Sourcewb.Worksheets
 
        'If the sheet is visible then copy it to a new workbook
        If sh.Visible = -1 Then
            sh.Copy
 
            'Set Destwb to the new workbook
            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-2013
                    If Sourcewb.name = .name Then
                        MsgBox "Your answer is NO in the security dialog"
                        GoTo GoToNextSheet
                    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
            If Destwb.Sheets(1).ProtectContents = False Then
                With Destwb.Sheets(1).UsedRange
                    .Cells.Copy
                    .Cells.PasteSpecial xlPasteValues
                    .Cells(1).Select
                End With
                Application.CutCopyMode = False
            End If
 
 
            'Save the new workbook and close it
            With Destwb
                .SaveAs FolderName _
                      & "" & Destwb.Sheets(1).name & FileExtStr, _
                        FileFormat:=FileFormatNum
                .Close False
            End With
 
        End If
GoToNextSheet:
    Next sh
 
    MsgBox "You can find the files in " & FolderName
 
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = xlCalculationAutomatic
    End With
End Sub
 
Last edited:

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Replace this part of the code
Rich (BB code):
    'Copy every sheet from the workbook with this macro
    Set Sourcewb = ThisWorkbook
by that one
Rich (BB code):
    'Copy every sheet from the ACTIVE workbook
    Set Sourcewb = ActiveWorkbook
 
Upvote 0
I noticed that the code saves the files correctly, but is saving them as .xls not .xlsm. Is it because my code resides in my personal.xlsb, and not in the ActiveWorkbook? I need the new files created to be .xlsm. Any help is appreciated :)
 
Upvote 0
Apply 3 corrections to your code as follows:

1. Replace
Rich (BB code):
FolderName = Sourcewb.Path & "" & Sourcewb.Name & " " & DateString
by
Rich (BB code):
FolderName = Sourcewb.Path & "\" & Sourcewb.Name & " " & DateString

2. Replace
Rich (BB code):
Case 52
by
Rich (BB code):
Case 52, 56

3. Replace
Rich (BB code):
        .SaveAs FolderName _
              & "" & Destwb.Sheets(1).Name & FileExtStr, _
               FileFormat:=FileFormatNum
by
Rich (BB code):
        .SaveAs FolderName _
              & "\" & Destwb.Sheets(1).Name & FileExtStr, _
                FileFormat:=FileFormatNum
 
Upvote 0
Thank you for your help! I have made the changes above, and it is still saving as .xls. I must be missing something... Here is my full current code:

Code:
Sub Copy_Every_Sheet_To_New_Workbook()
    Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim Sourcewb As Workbook
    Dim Destwb As Workbook
    Dim sh As Worksheet
    Dim DateString As String
    Dim FolderName As String
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
        .Calculation = xlCalculationManual
    End With
    'Copy every sheet from the workbook with this macro
    Set Sourcewb = ActiveWorkbook
    'Create new folder to save the new files in
    DateString = Format(Now, "yyyy-mm-dd hh-mm-ss")
    FolderName = Sourcewb.Path & "\" & Sourcewb.name & " " & DateString
    MkDir FolderName
    'Copy every visible sheet to a new workbook
    For Each sh In Sourcewb.Worksheets
        'If the sheet is visible then copy it to a new workbook
        If sh.Visible = -1 Then
            sh.Copy
            'Set Destwb to the new workbook
            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-2013
                    If Sourcewb.name = .name Then
                        MsgBox "Your answer is NO in the security dialog"
                        GoTo GoToNextSheet
                    Else
                        Select Case Sourcewb.FileFormat
                        Case 51: FileExtStr = ".xlsx": FileFormatNum = 51
                        Case 52, 56:
                            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
            If Destwb.Sheets(1).ProtectContents = False Then
                With Destwb.Sheets(1).UsedRange
                    .Cells.Copy
                    .Cells.PasteSpecial xlPasteValues
                    .Cells(1).Select
                End With
                Application.CutCopyMode = False
            End If

            'Save the new workbook and close it
            With Destwb
                .SaveAs FolderName _
                      & "\" & Destwb.Sheets(1).name & FileExtStr, _
                        FileFormat:=FileFormatNum
                        
                .Close False
            End With
        End If
GoToNextSheet:
    Next sh
    MsgBox "You can find the files in " & FolderName
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = xlCalculationAutomatic
    End With
End Sub
 
Upvote 0
I also need to change the sheet1 (in each new saved workbook) to be "Teacher". Was thinking I should add ActiveSheet.name = "Teacher" after the .SaveAs FolderName, but it's not changing the sheet name. Do you have any ideas where I'm going wrong with this?
 
Upvote 0
Unfortunately, I am still stuck on this. Any ideas? Cannot get it to save as "macro enabled", and need to for the next step. Also need sheet1 to be "Teacher" for next code to work. Help!
 
Upvote 0
The logic of your code is as follows:

1. If code runs in Excel 2007...2016 then sheets of workbook Wb1.XLS are saved in separate files with extensions XLSX (sheet without macro) or XLSM (sheet with macro) in the folder named like this:
Wb1.xls 2016-09-14 12-44-49
There is xls part in the folder name because of extension of the original workbook.

2. The file names of the saved sheets in that folder are:
- Sheet1.xlsx without macro in it
- Sheet2.xlsm with macro included
etc

3. If code runs in Excel 2003 then all sheets are saved with XLS extension.

Could you please describe in which point of that logic problem happens?
Or what do you expect instead of the described logic?

To save the 1st sheet as "Teacher" insert one more line of code after the line With Destwb like this:
Rich (BB code):
      With Destwb
        ' The 1st saved sheet is renamed to "Teacher"
        If .Sheets(1).Name = Sourcewb.Sheets(1).Name Then .Sheets(1).Name = "Teacher"
 
Last edited:
Upvote 0
Thank you for helping! I am using Excel 2013, and it accurately creates a folder All Teacher Workbook.xlsm 2016-09-13 15-51-24. But each individual workbook in that folder are Sheet1.xlsx, Sheet2.xlsx, etc., and not .xlsm (macro enabled). I need the individual workbooks in the folder to be Sheet1.xlsm

The additional code is great! Thank you!!!
 
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

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