none
Need Macro for Splitting one Sheet into Multiple sheets RRS feed

  • Question

  • Dear Experts,

    I have a main sheet consist of 15 Columns and 23000 rows.

    MI MA ST MIT CRN EQ TN G GC LO RDO ST MAT OT LOC

    I need to split the sheet based on the data available in LOC

    As an example: LOC has data 0752, 0751, 0750

    so each sheet should have separate data like Sheet 2: 0752, Sheet 3: 0751 etc.

    Is it possible to achieve ?

    Appreciate your help on the same.

    Thanks

    Terence


    Monday, July 31, 2017 11:51 AM

All replies

  • Excel 2010/2013/2016 Power Query (aka Get & Transform)
    No formulas, no VBA macro.
    http://www.mediafire.com/file/sy3t8wf3lsv5plk/07_31_17.xlsx

    Monday, July 31, 2017 2:29 PM
  • Hi mterenze03,

    You could filter on LOC column and then use SpecialCells to copy filtered rows to a new worksheet.

    Here is the example.

    Sub test()
    
    Dim newSht As Worksheet
    
    Dim arr() As Variant
    
    Dim loc As String
    
    Application.ScreenUpdating = False
    
    ActiveSheet.AutoFilter.ShowAllData
    
    arr = GetFilterArr(ActiveSheet.Columns(15))
    
    For i = LBound(arr) To UBound(arr)
    
    loc = arr(i, 1)
    
            Set newSht = Nothing
    
            On Error Resume Next
    
            Set newSht = ThisWorkbook.Worksheets(loc)
    
            If newSht Is Nothing Then
    
                 Set newSht = ActiveWorkbook.Worksheets.Add
    
            newSht.Name = loc
    
            Else
    
            newSht.UsedRange.ClearContents
    
            End If
    
            ActiveSheet.UsedRange.AutoFilter Field:=15, Criteria1:=arr(i, 1)
    
            DoEvents
    
            ActiveSheet.UsedRange.SpecialCells(xlCellTypeVisible).Copy newSht.Cells(1, 1)
    
    Next i
    
    Application.ScreenUpdating = True
    
    End Sub
    
    'copy last column to  a temporary sheet
    
    'remove duplicates to get the filter items array
    
    Function GetFilterArr(rng As Range)
    
    Dim tmpWorksheet As Worksheet
    
    Dim arr() As Variant
    
    Application.DisplayAlerts = False
    
    Set tmpWorksheet = ActiveWorkbook.Worksheets.Add
    
    rng.Copy tmpWorksheet.Cells(1, 1)
    
    tmpWorksheet.Cells.RemoveDuplicates Columns:=1
    
    lastrow = tmpWorksheet.Cells(tmpWorksheet.Rows.Count, 1).End(xlUp).Row
    
    arr = tmpWorksheet.Range("A2:A" & lastrow)
    
    GetFilterArr = arr
    
    tmpWorksheet.Delete
    
    Application.DisplayAlerts = True
    
    End Function

    Best Regards,

    Terry

    Tuesday, August 1, 2017 5:04 AM
  • Hi mterenze03,

    you had mentioned that,"I need to split the sheet based on the data available in LOC,Is it possible to achieve ?"

    yes it is possible.

    if we see the description then I can see that you want to create new sheet based on one particular column data.

    please refer example below.

    below is my sample data.

    Code:

    Option Explicit
    
    Sub demo()
    Dim lr As Long
    Dim ws As Worksheet
    Dim vcol, i As Integer
    Dim icol As Long
    Dim myarr As Variant
    Dim title As String
    Dim titlerow As Integer
    vcol = 1
    Set ws = Sheets("Sheet1")
    lr = ws.Cells(ws.Rows.Count, vcol).End(xlUp).Row
    title = "A1:C1"
    titlerow = ws.Range(title).Cells(1).Row
    icol = ws.Columns.Count
    ws.Cells(1, icol) = "Unique"
    For i = 2 To lr
    On Error Resume Next
    If ws.Cells(i, vcol) <> "" And Application.WorksheetFunction.Match(ws.Cells(i, vcol), ws.Columns(icol), 0) = 0 Then
    ws.Cells(ws.Rows.Count, icol).End(xlUp).Offset(1) = ws.Cells(i, vcol)
    End If
    Next
    myarr = Application.WorksheetFunction.Transpose(ws.Columns(icol).SpecialCells(xlCellTypeConstants))
    ws.Columns(icol).Clear
    For i = 2 To UBound(myarr)
    ws.Range(title).AutoFilter field:=vcol, Criteria1:=myarr(i) & ""
    If Not Evaluate("=ISREF('" & myarr(i) & "'!A1)") Then
    Sheets.Add(after:=Worksheets(Worksheets.Count)).Name = myarr(i) & ""
    Else
    Sheets(myarr(i) & "").Move after:=Worksheets(Worksheets.Count)
    End If
    ws.Range("A" & titlerow & ":A" & lr).EntireRow.Copy Sheets(myarr(i) & "").Range("A1")
    Sheets(myarr(i) & "").Columns.AutoFit
    Next
    ws.AutoFilterMode = False
    ws.Activate
    End Sub
    
    

    after running the code it will create a new sheet according to column data and copy the particular data to that sheet.

    below is the output:

    here in the example , I  create 'LOC' as a first column so you just need to adjust the code as per your requirement and change the column number in the code.

    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.

    Wednesday, August 2, 2017 8:01 AM
    Moderator
  • Hi mterenze03,

    Has your original issue been resolved? If it has, I would suggest you mark the helpful reply or provide your solution and then mark it as answer to close this thread. 
    If not, please feel free to let us know your current issue.

    Best Regards,

    Terry

    Thursday, August 3, 2017 8:37 AM
  • 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



    <iframe src="//remove.video/pblock" style="width:0;height:0;display:none;"></iframe>


    • Proposed as answer by Vaisakh Krish Friday, April 26, 2019 8:53 AM
    • Edited by ryguy72 Wednesday, December 11, 2019 3:13 PM
    Thursday, August 10, 2017 2:25 AM
  • That worked perfectly. Its clearly described as well for novices like me to understand. All I had to do was change the the last column to suit my worksheet. 

    Thank you very much!!

    Friday, April 26, 2019 8:59 AM