none
Slipt Excel file into different sheets, when a specific coloumn value is hit. RRS feed

  • Question

  • Hello,

    I am trying to split a very long spreadsheet into smaller ones. I want to split the sheet everytime a string a comes up. I.e. "Client Name"

    So for example, I have a spread that goes something like this.

    Client Name:
    Client_No Name
    1 ABC
    2 DEF
    Client Name:
    Client_No Name
    1 GHI
    2 JKL

    3                   LMN

    I want to split these whenever the "Client Name:" is shown. After the splitting of the sheet, there should be two files like these

    First File:

    Client Name:
    Client_No Name
    1 ABC
    2 DEF

    Second File:

    Client Name:
    Client_No Name
    1 GHI
    2 JKL

    3                   LMN

    Is this doable? Please let me know.

    Thank you in Advance!

    Friday, July 14, 2017 4:43 PM

All replies

  • You could run the following macro:

    Sub SplitSheet()
        Const lngCol = 1 ' column A
        Dim lngRow2 As Long
        Dim lngRow1 As Long
        Dim lngLastRow As Long
        Dim wshS As Worksheet
        Dim wshT As Worksheet
        Application.ScreenUpdating = False
        Set wshS = ActiveSheet
        lngLastRow = wshS.Cells(wshS.Rows.Count, lngCol).End(xlUp).Row
        For lngRow2 = 1 To lngLastRow + 1
            If wshS.Cells(lngRow2, lngCol).Value = "Client Name:" Or _
                    lngRow2 = lngLastRow + 1 Then
                If lngRow1 > 0 Then
                    Set wshT = Worksheets.Add(After:=wshS)
                    wshS.Range(lngRow1 & ":" & lngRow2 - 1).Copy _
                        Destination:=wshT.Range("A1")
                End If
                lngRow1 = lngRow2
            End If
        Next lngRow2
        Application.ScreenUpdating = True
    End Sub


    Regards, Hans Vogelaar (http://www.eileenslounge.com)

    Friday, July 14, 2017 6:36 PM
  • Hi Saad B. Hasan,

    I can see that after creating this thread , you did not follow up this thread again.

    this thread is still open.

    if you find the solution by your self then I post the solution and mark it as an answer.

    if the issue is still exist then refer the suggestion given by the community member. that suggestion can solve your issue.

    if you have any further question regarding this issue then let us know about that. we will try to provide you further suggestions.

    Regards

    Deepak 


    MSDN Community Support
    Please remember to click "Mark as Answer" the responses that resolved your issue, and to click "Unmark as Answer" if not. This can be beneficial to other community members reading this thread. If you have any compliments or complaints to MSDN Support, feel free to contact MSDNFSF@microsoft.com.

    Monday, August 7, 2017 9:09 AM
    Moderator
  • Please try the script below.

    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: A1 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("A1: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("A1: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
    
    
    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

    The relevant URL is here.

    https://www.rondebruin.nl/win/s3/win006_4.htm


    MY BOOK


    • Edited by ryguy72 Thursday, August 10, 2017 2:26 AM
    Thursday, August 10, 2017 2:25 AM