Apr 14 2022 10:33 AM - edited Apr 14 2022 10:42 AM
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.
Apr 14 2022 12:34 PM
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
Nov 22 2022 08:32 AM
I am looking to save the separate files in particular folder. What line would the file location replace?
Nov 22 2022 01:09 PM
Line 51 now says
MyPath = ThisWorkbook.Path
Change this to
MyPath = "..."
where ... is the path of the target folder.
Jan 09 2023 01:54 PM
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?
Jan 09 2023 02:20 PM
Does this work?
WSNew.Parent.SaveAs MyPath & WSNew.Range("C2") & "_" & cell.Value & FileExtStr, FileFormatNum
Apr 18 2024 03:18 AM
Apr 18 2024 03:54 AM
I'm sorry, I don't understand what you want. Can you explain it more clearly, and in detail? Thanks in advance.
Apr 18 2024 06:12 AM
Thought as well i would have made it complicated.
Attached image shows the master file which has the serial numbers (identified in BLUE BOX).
The image next to it is one of the split files, but the serial numbers in this file is #VALUE.
Wanted to check if the split files (second image) can also have serial numbers mentioned.
Apr 18 2024 06:20 AM
The code that I posted pastes the data as values, i.e. without formulas, so the sequence numbers should be preserved.
Do you want the sequence numbers to start with 1 in each file?
Apr 18 2024 07:28 PM
Yes, i'd love for them to start the sequence with 1. This would put an end to the little manual intervention required.
Apr 19 2024 12:43 AM
Immediately above the line
'Save the file in the new folder and close it
insert
'Fill column A
WSNew.Range(WSNew.Range("A2"), WSNew.Range("A1").End(xlDown)).Formula = "=ROW()-1"
Jun 18 2024 12:19 PM
@HansVogelaar This thread has been very helpful.
Is it possible when using a macro to separate data into new workbooks, to drop the data into new files that contain formulas?
For example, we have sales totals for different areas. The macro allows us to be able to move those sales by area to a new file which is great, but we would like to have some formulas above the data that sum different columns. So the data would need to drop in on line row 10, instead of row 1.
Jun 18 2024 01:14 PM
In the long macro that I posted in my first reply, change line 90 to
With WSNew.Range("A10")
Jun 18 2024 01:35 PM
@HansVogelaar Is there a way to bring over the formulas that I have in the first 10 rows of my main file to the individual files? The formulas just sum a few of the columns and calculate a ratio.
Jun 18 2024 02:35 PM
Could you attach a small sample workbook so that I can experiment? Thanks in advance.
Jun 19 2024 05:53 AM
@HansVogelaar Hello Hans. Below is an example.
The macro you provided already did a great job breaking out my report based on region below into individual files. What I am wanting to do though is include the 3 sample formulas in the individual files. So each file would contain sales for just 1 region, with a few formulas at top summing the totals, calculating a %, etc. Thanks!
Jun 19 2024 06:12 AM - edited Jun 19 2024 06:12 AM
I repeat the request from my previous reply.
Jun 19 2024 06:22 AM
@HansVogelaar Sorry, but I'm getting an error that the file type (.xlsm, .xlsx and .xls) are not supported, so unable to attach copy.
Jun 19 2024 07:13 AM
You can upload the workbook to a cloud storage such as Google Drive, OneDrive or Dropbox.
Post a link to the uploaded file in a reply.