Forum Discussion

CWsChim's avatar
CWsChim
Copper Contributor
Jan 19, 2024
Solved

VBA script for a Macro

Hello all,

 

I am new to VB scripting and Macro's in general so this may be a naïve question. My apologies if so.

 

I have an excel file that contains data on members belonging to organizations my company is contracted with. There are over 100 different organizations we have contracts with and over 60,000 members. I am wanting to write a Macro that will go through the data (lives on Sheet1) and for every contracted organization, I want to copy the header row and every row of members for that organization and paste that data on it's own sheet and ideally the new sheet is named whatever the organization is called in the source data. Ultimately I want to have a new sheet for every unique organization and all of the members belonging to that organization are on that sheet. I have played with a couple scripts I was able to strangle out of Chat GPT, but ultimately was unsuccessful so I am hoping actual humans can help me!

 

I'm sure this is run of the mill code, but could be a great and useful place to start writing Macros and utilizing VB.

 

Thank you for any help you can provide!

 

 

 

 

 

  • CWsChim 

    Here is a variation of code originally written by Ron de Bruin. The macro Copy_To_Worksheets has a line

     

    fieldNum = 1

     

    This specifies the first column (column A) as the column with the names of the organizations.

    Change this as needed. For example, if the organizations are in column D, change the above line to

     

    fieldNum = 4

    Sub Copy_To_Worksheets()
        'Note: This macro uses the function LastRow
        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 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
    
        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))
        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 = Worksheets.Add(Before:=ws2)
                    On Error Resume Next
                    WSNew.Name = Left(cell.Value, 31)
                    On Error GoTo 0
    
                    '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
                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
    
    Function LastRow(sh As Worksheet)
        On Error Resume Next
        LastRow = sh.Cells.Find(What:="*", _
                                After:=sh.Range("A1"), _
                                Lookat:=xlPart, _
                                LookIn:=xlValues, _
                                SearchOrder:=xlByRows, _
                                SearchDirection:=xlPrevious, _
                                MatchCase:=False).Row
        On Error GoTo 0
    End Function
  • djclements's avatar
    djclements
    Bronze Contributor

    CWsChim With 60,000+ rows of data, you may want to consider using the Advanced Filter method. It's extremely fast and requires very little code; plus, the cell formatting of the source data is automatically applied to the output range. The only setup that's required is to designate a criteria range and output range.

     

    For example, consider the following sample data on "Sheet1" with column headers for "Organization", "Member", "Position" and "Department":

     

    Sample Data

     

    First, create a new sheet called "AdvFilter", then copy the "Organization" header into cell A1 (the criteria range) and cell A5 (the output range). The setup should look something like this:

     

    Advanced Filter Setup

     

    Then, the code to filter the data for each "Organization" and output the results to a new worksheet would be as follows:

     

    Option Explicit
    
    Sub CopyDataToNewSheets()
    
        On Error GoTo ErrorHandler
    
        Application.ScreenUpdating = False
        Application.Calculation = xlCalculationManual
    
    'Get the unique organization list
        Dim wsFilter As Worksheet, wsData As Worksheet, rgData As Range
        Set wsFilter = Sheets("AdvFilter")
        Set wsData = Sheets("Sheet1")
        Set rgData = wsData.Range("A1").CurrentRegion
        Call AdvFilter(rgData, wsFilter.Range("A1").CurrentRegion, wsFilter.Range("A5"), True)
    
    'Load the header row into an array
        Dim headers As Variant, cols As Long
        headers = rgData.Rows(1).Value
        cols = UBound(headers, 2)
    
    'Sort the organization list
        Dim rg As Range
        Set rg = wsFilter.Range("A5").CurrentRegion
        rg.Sort Key1:=rg.Columns(1), Header:=xlYes
    
    'Loop through the list
        Dim i As Long, str As String, wsOutput As Worksheet
        For i = 2 To rg.Rows.Count
        ' get the organization name
            str = rg.Cells(i, 1).Value
        ' add a new worksheet
            Set wsOutput = Worksheets.Add(, Sheets(Sheets.Count))
        ' attempt to rename the worksheet
            On Error Resume Next
            wsOutput.Name = str
            On Error GoTo ErrorHandler
        ' write the header row to the worksheet
            With wsOutput.Range("A1").Resize(, cols)
                .Value = headers
                .Font.Bold = True
            End With
        ' output the organization data to the worksheet
            wsFilter.Range("A2").Value = "'=" & Replace(Replace(str, "*", "~*"), "?", "~?")
            Call AdvFilter(rgData, wsFilter.Range("A1").CurrentRegion, wsOutput.Range("A1"))
            wsOutput.Range("A1").CurrentRegion.EntireColumn.AutoFit
        ' remove auto-defined name
            wsOutput.Names("Extract").Delete
        Next i
        wsData.Select
    
    CleanUp:
        Application.Calculation = xlCalculationAutomatic
        Application.ScreenUpdating = True
        Exit Sub
    
    ErrorHandler:
        MsgBox Err.Description, vbExclamation, "Runtime Error: " & Err.Number
        Err.Clear
        GoTo CleanUp
    
    End Sub
    
    Private Sub AdvFilter(sourceRng As Range, criteriaRng As Range, outputRng As Range, Optional optUnique As Boolean)
        
    'Clear the previous results
        outputRng.CurrentRegion.Offset(1).ClearContents
    
    'Output the new results
        On Error Resume Next
        sourceRng.AdvancedFilter xlFilterCopy, criteriaRng, outputRng.CurrentRegion, optUnique
    
    End Sub

     

    Note: the CopyDataToNewSheets procedure above is written for one-time use; however, with a few small adjustments, it can easily be made to update the data on each worksheet over and over again using the AdvFilter procedure.

  • CWsChim 

    Here is a variation of code originally written by Ron de Bruin. The macro Copy_To_Worksheets has a line

     

    fieldNum = 1

     

    This specifies the first column (column A) as the column with the names of the organizations.

    Change this as needed. For example, if the organizations are in column D, change the above line to

     

    fieldNum = 4

    Sub Copy_To_Worksheets()
        'Note: This macro uses the function LastRow
        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 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
    
        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))
        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 = Worksheets.Add(Before:=ws2)
                    On Error Resume Next
                    WSNew.Name = Left(cell.Value, 31)
                    On Error GoTo 0
    
                    '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
                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
    
    Function LastRow(sh As Worksheet)
        On Error Resume Next
        LastRow = sh.Cells.Find(What:="*", _
                                After:=sh.Range("A1"), _
                                Lookat:=xlPart, _
                                LookIn:=xlValues, _
                                SearchOrder:=xlByRows, _
                                SearchDirection:=xlPrevious, _
                                MatchCase:=False).Row
        On Error GoTo 0
    End Function
    • CWsChim's avatar
      CWsChim
      Copper Contributor
      This worked perfectly! Thank you so much!

Resources