+ Reply to Thread
Results 1 to 3 of 3

Macro to split workbook into multiple workbooks by client name

Hybrid View

  1. #1
    Registered User
    Join Date
    08-01-2012
    Location
    us
    MS-Off Ver
    Excel 2003
    Posts
    5

    Macro to split workbook into multiple workbooks by client name

    I'm looking for a Macro that will take a column of names and create an excel file for each name. The row data plus a header should carryover.

    The excel file name should be derived from the name in Column B. Note that many rows will have duplicate names since each client name may have different data points, but they need to receive a single backup file per name.

  2. #2
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Macro to split workbook into multiple workbooks by client name

    Do you have a sample file that you can upload?

    To Attach a File:

    1. Click on Go Advanced
    2. In the frame Attach Files you will see the button Manage Attachments
    3. Click the button.
    4. A new window will open titled Manage Attachments - Excel Forum.
    5. Click the Browse... button to locate your file for uploading.
    6. This will open a new window File Upload.
    7. Once you have located the file to upload click the Open button. This window will close.
    8. You are now back in the Manage Attachments - Excel Forum window.
    9. Click the Upload button and wait until the file has uploaded.
    10. Close the window and then click Submit.
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

  3. #3
    Registered User
    Join Date
    04-23-2013
    Location
    Singapore
    MS-Off Ver
    Excel 2010
    Posts
    56

    Re: Macro to split workbook into multiple workbooks by client name

    Hi Avalerion,

    Please try this if it works

    Best Regards,
    Narasimharao


    Sub Copy_To_Worksheets()
    'Note: This macro use the function LastRow
        Dim My_Range As Range
        Dim FieldNum As Long
        Dim CalcMode As Long
        Dim ViewMode As Long
        Dim ws2 As Worksheet
        Dim Lrow As Long
        Dim cell As Range
        Dim CCount As Long
        Dim WSNew As Worksheet
        Dim ErrNum As Long
    
        'Set filter range on ActiveSheet: A11 is the top left cell of your filter range
        'and the header of the first column, D is the last column in the filter range.
        'You can also add the sheet name to the code like this :
        'Worksheets("Sheet1").Range("A11:D" & LastRow(Worksheets("Sheet1")))
        'No need that the sheet is active then when you run the macro when you use this.
        Set My_Range = Range("A11:D" & LastRow(ActiveSheet))
        My_Range.Parent.Select
    
        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 worksheet"
            Exit Sub
        End If
    
        'This example filters on the first column in the range(change the field if needed)
        'In this case the range starts in A so Field:=1 is column A, 2 = column B, ......
        FieldNum = 1
    
        'Turn off AutoFilter
        My_Range.Parent.AutoFilterMode = False
    
        '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
    
        'Add a worksheet to copy the a unique list and add the CriteriaRange
        Set ws2 = Worksheets.Add
    
        With ws2
            'first we copy the Unique data from the filter field to ws2
            My_Range.Columns(FieldNum).AdvancedFilter _
                    Action:=xlFilterCopy, _
                    CopyToRange:=.Range("A1"), 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("A2: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 a new worksheet
                    Set WSNew = Worksheets.Add(After:=Sheets(Sheets.Count))
                    On Error Resume Next
                    WSNew.Name = cell.Value
                    If Err.Number > 0 Then
                        ErrNum = ErrNum + 1
                        WSNew.Name = "Error_" & Format(ErrNum, "0000")
                        Err.Clear
                    End If
                    On Error GoTo 0
    
                    'Copy the visible data to the new worksheet
                    My_Range.SpecialCells(xlCellTypeVisible).Copy
                    With WSNew.Range("A1")
                        ' Paste:=8 will copy the columnwidth in Excel 2000 and higher
                        ' Remove this line if you use Excel 97
                        .PasteSpecial Paste:=8
                        .PasteSpecial xlPasteValues
                        .PasteSpecial xlPasteFormats
                        Application.CutCopyMode = False
                        .Select
                    End With
                End If
    
                'Show all data in the range
                My_Range.AutoFilter Field:=FieldNum
    
            Next cell
    
            'Delete the ws2 sheet
            On Error Resume Next
            Application.DisplayAlerts = False
            .Delete
            Application.DisplayAlerts = True
            On Error GoTo 0
    
        End With
    
        'Turn off AutoFilter
        My_Range.Parent.AutoFilterMode = False
    
        If ErrNum > 0 Then
            MsgBox "Rename every WorkSheet name that start with ""Error_"" manually" _
                 & vbNewLine & "There are characters in the name that are not allowed" _
                 & vbNewLine & "in a sheet name or the worksheet already exist."
        End If
    
        'Restore ScreenUpdating, Calculation, EnableEvents, ....
        My_Range.Parent.Select
        ActiveWindow.View = ViewMode
        With Application
            .ScreenUpdating = True
            .EnableEvents = True
            .Calculation = CalcMode
        End With
    
    End Sub

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Split a workbook into multiple workbooks
    By stewfeed in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 04-30-2013, 07:15 AM
  2. How to split workbook into multiple workbooks based on date range
    By simoncurrier in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 02-28-2013, 06:50 AM
  3. [SOLVED] Split Macro modification to Split into new Workbooks instead of sheets within one workbook
    By DLSmith in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 07-13-2012, 08:11 PM
  4. Split .xlsm workbook into multiple xlxs. workbooks
    By thelenw in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 11-29-2011, 04:28 PM
  5. [SOLVED] Macro to Split Workbook into separate Workbooks
    By jmurray in forum Excel Programming / VBA / Macros
    Replies: 12
    Last Post: 07-14-2009, 04:44 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1