VBA to break a spreadsheet into many within a zip file

vmackey

New Member
Joined
Jun 4, 2019
Messages
6
Hello. I am new to forum, a novice in excel and learning VBA. I have a request from my boss to see if I could develop a button that will break up a single spreadsheet "billing" file into multiple spreadsheets to upload into our billing software. The specs would include:

1. A new spreadsheet will be created whenever a "client" name or value changes in column A.
2. Ideally the spreadsheets will be combined in a zip file, but this is not required.
3. Ideally the macro would be assigned to a "button" but also not required
4. When exported, the content would be void of formulas and duplicated as values only.
5. The header from the original spreadsheet would need to be transferred into all new spreadsheets.

Some details on the file:
1. There are multiple tabs (11 in total)
2. The tab needed for export has data filling 35 columns, but I only want to export up to the 29th column.
3. Each month's data would be approximately 3200-3500 rows
4. there are approximately 195 "clients" meaning the macro would need to create 195 spreadsheets.
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
2. The tab needed for export has data filling 35 columns, but I only want to export up to the 29th column.

If there is only on Sheet out of 11 that needs to be worked, if so, what is the sheet name?
Will the workbook containing the source data be open at runtime? If not and the directory path is different than the workbook hosting the code, then provide the path for opening the workbook.
Will the code be hosted by a workbook other than the source workbook?
 
Upvote 0
Hello, thank you for responding and apologies for the delayed response. Answers to your questions below:

1. The sheet is named "Template Creation"

2. Yes, the workbook containing the source data will be open at runtime

3. No, the code will not be hosted by a workbook other than the source workbook.
 
Upvote 0
This assumes that the headers are in row 1 and data begins in row 2 of sheet 'Template Creation'.
Code:
Sub t()
Dim lr As Long, sh As Worksheet, c As Range, wb As Workbook
Application.Calculation = xlCalulationManual
Set sh = Sheets("Template Creation")
lr = sh.Cells.Find("*", , xlFormulas, xlPart, xlByRows, xlPrevious).Row
    With sh
        .Range("A1:A" & lr).AdvancedFilter xlFilterCopy, , .Range("B" & lr + 2), True
        For Each c In Range("B" & lr + 2).CurrentRegion.Offset(1)
            If c <> "" Then
                .UsedRange.AutoFilter 1, c.Value
                Set wb = Workbooks.Add
               .Range("A1:AC" & lr).SpecialCells(xlCellTypeVisible).Copy
                wb.Sheets(1).Range("A1").PasteSpecial xlPasteValues
                wb.SaveAs ThisWorkbook.Path & "\" & c.Value & ".xlsx"
                wb.Close False
                .AutoFilterMode = False
            End If
        Next
        .Range("B" & lr + 2).CurrentRegion.ClearContents
    End With
Application.Calculation = xlCalculationAutomatic
End Sub
This should take about three to five minutes to do 195 clients.
 
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,196
Members
452,616
Latest member
intern444

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