Forum Discussion
Jlee0730
Apr 14, 2022Copper Contributor
Macro to split excel into separate workbooks
Please help. I am not new to excel but new to macros and VBAs, I have a large spreadsheet that I would like the data to pull out specific date based on a column and then create a separate workbook for each heading.
Here is a sample of the workbook. I would like it to create new workbooks in the same format, with just the individual site information in each workbook. And the workbooks would be named after the sites. Any help would be appreciated.
I found a you tube and worked through it, but it would only create new worksheets within the workbook, with the site names as the sheet names and copy the heading line, but no data and then I kept getting an activesheet.name = cell.value error.
Here are two examples of what I would like it to look like after running the macro on the master data.
23 Replies
Sort By
Try this (based on an example by Ron de Bruin):
Sub Copy_To_Workbooks() Dim My_Range As Range Dim FieldNum As Long Dim FileExtStr As String Dim FileFormatNum As Long Dim CalcMode As Long Dim ViewMode As Long Dim ws2 As Worksheet Dim MyPath As String Dim foldername As String Dim Lrow As Long Dim cell As Range Dim CCount As Long Dim WSNew As Worksheet Dim ErrNum As Long Set My_Range = ActiveSheet.UsedRange If ActiveWorkbook.ProtectStructure = True Or _ My_Range.Parent.ProtectContents = True Then MsgBox "Sorry, not working when the workbook or worksheet is protected", _ vbOKOnly, "Copy to new workbook" Exit Sub End If 'This example filters on the 7th column in the range FieldNum = 7 'Turn off AutoFilter My_Range.Parent.AutoFilterMode = False FileExtStr = ".xlsx" FileFormatNum = xlOpenXMLWorkbook 'Change ScreenUpdating, Calculation, EnableEvents, .... With Application CalcMode = .Calculation .Calculation = xlCalculationManual .ScreenUpdating = False .EnableEvents = False End With ViewMode = ActiveWindow.View ActiveWindow.View = xlNormalView ActiveSheet.DisplayPageBreaks = False My_Range.Sort Key1:=Cells(1, FieldNum), Header:=xlYes ' Add worksheet to copy/paste the unique list Set ws2 = Worksheets.Add(After:=Sheets(Sheets.Count)) MyPath = ThisWorkbook.Path 'Add a slash at the end if the user forget it If Right(MyPath, 1) <> "\" Then MyPath = MyPath & "\" End If With ws2 'first we copy the Unique data from the filter field to ws2 My_Range.Columns(FieldNum).AdvancedFilter _ Action:=xlFilterCopy, _ CopyToRange:=.Range("A3"), Unique:=True 'loop through the unique list in ws2 and filter/copy to a new sheet Lrow = .Cells(Rows.Count, "A").End(xlUp).Row For Each cell In .Range("A4:A" & Lrow) 'Filter the range My_Range.AutoFilter Field:=FieldNum, Criteria1:="=" & _ Replace(Replace(Replace(cell.Value, "~", "~~"), "*", "~*"), "?", "~?") 'Check if there are no more then 8192 areas(limit of areas) CCount = 0 On Error Resume Next CCount = My_Range.Columns(1).SpecialCells(xlCellTypeVisible) _ .Areas(1).Cells.Count On Error GoTo 0 If CCount = 0 Then MsgBox "There are more than 8192 areas for the value : " & cell.Value _ & vbNewLine & "It is not possible to copy the visible data." _ & vbNewLine & "Tip: Sort your data before you use this macro.", _ vbOKOnly, "Split in worksheets" Else 'Add new workbook with one sheet Set WSNew = Workbooks.Add(xlWBATWorksheet).Worksheets(1) WSNew.Name = cell.Value 'Copy/paste the visible data to the new workbook My_Range.SpecialCells(xlCellTypeVisible).Copy With WSNew.Range("A1") .PasteSpecial Paste:=xlPasteColumnWidths .PasteSpecial xlPasteValues .PasteSpecial xlPasteFormats Application.CutCopyMode = False .Select End With 'Save the file in the new folder and close it On Error Resume Next WSNew.Parent.SaveAs MyPath & cell.Value & FileExtStr, FileFormatNum WSNew.Parent.Close False On Error GoTo 0 End If 'Show all the data in the range My_Range.AutoFilter Field:=FieldNum Next cell End With 'Turn off AutoFilter My_Range.Parent.AutoFilterMode = False 'Restore ScreenUpdating, Calculation, EnableEvents, .... My_Range.Parent.Select ActiveWindow.View = ViewMode Application.DisplayAlerts = False ws2.Delete Application.DisplayAlerts = True With Application .ScreenUpdating = True .EnableEvents = True .Calculation = CalcMode End With End Sub
- adsuarezCopper Contributor
I am a VBA novice, so any help is appreciated. I have this Macro working, but I'm trying to add another component to the file name. For example, in the new worksheet, I want the value in cell C2 to always be part of the file name. But when I do something like below, the Macro runs with no errors, but doesn't actually produce any files...
WSNew.Parent.SaveAs MyPath & Range("C2") & "_" & cell.Value & FileExtStr, FileFormatNum
Any ideas?
Does this work?
WSNew.Parent.SaveAs MyPath & WSNew.Range("C2") & "_" & cell.Value & FileExtStr, FileFormatNum
- Richard_Miller_1985Copper Contributor
I am looking to save the separate files in particular folder. What line would the file location replace?
Line 51 now says
MyPath = ThisWorkbook.Path
Change this to
MyPath = "..."
where ... is the path of the target folder.