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.
 

JLGWhiz

Well-known Member
Joined
Feb 7, 2012
Messages
11,291
Office Version
2013
Platform
Windows
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?
 

vmackey

New Member
Joined
Jun 4, 2019
Messages
6
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.
 

JLGWhiz

Well-known Member
Joined
Feb 7, 2012
Messages
11,291
Office Version
2013
Platform
Windows
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.
 

vmackey

New Member
Joined
Jun 4, 2019
Messages
6
Wow!!! This works fantastically! Thank you very much, you're very talented!!
 

JLGWhiz

Well-known Member
Joined
Feb 7, 2012
Messages
11,291
Office Version
2013
Platform
Windows
Happy to help,
regards, JLG
 

Forum statistics

Threads
1,082,295
Messages
5,364,359
Members
400,792
Latest member
Dxmiian

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top