Forum Discussion

robgill205's avatar
robgill205
Copper Contributor
Jul 14, 2023

Macro for categorising data

Hi,

I have a sheet of raw data. I would like to know if its possible to categorise it by Department. 

Meaning, I would like to create new files for each department instead of them being mixed together as I show in a small example that is attached. For example, all the rows with "Asset Management" would be put in a fold named "Asset Management". This would then give me multiple folders separated by the department name.

Thank for you any help in advance and let me know if you need more information.

  • robgill205 

    The following code is based on an example by Ron de Bruin.

    Sub Copy_To_Workbooks()
        '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 second  column in the range(change the field if needed)
        'In this case the range starts in B so FieldNum = 2
        FieldNum = 2
    
        '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)
    
                    '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
    
    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

    See the attached workbook (now a macro-enabled workbook).

Resources