Copy rows with "like" values in A column into new sheets

ExcelNoob11

New Member
Joined
Jul 17, 2018
Messages
7
I have a workbook with a table that I need to subdivide into individual sheets.

The table has 7 columns. In column A it has the name of a device.

For example:
ColumnAColumnBColumnCColumnDColumnEColumnFColumnG
Device1
Device1
Device1
Device2
Device2
Device3

<tbody>
</tbody>

I'd like to take all the rows with "Device1" and copy them to a new sheet with "Device1" as the name of the sheet. Then proceed to do it for Device2, Device3, and DevinceN.

Can anyone point me in the right direction?

Kind regards,
ExcelNoobie
 

Some videos you may like

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
9,598
This macro assumes you have headers in row 1 and the sheet with the data is named "Sheet1".
Code:
Sub CreateSheet()
    Application.ScreenUpdating = False
    Dim bottomA As Long
    bottomA = Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row
    Dim rName As Range
    Dim ws As Worksheet
    Dim rngUniques As Range
    Sheets("Sheet1").Range("A1:A" & bottomA).AdvancedFilter Action:=xlFilterInPlace, CriteriaRange:=Range _
        ("A1:A" & bottomA), Unique:=True
    Set rngUniques = Sheets("Sheet1").Range("A2:A" & bottomA).SpecialCells(xlCellTypeVisible)
    If Sheets("Sheet1").AutoFilterMode = True Then Sheets("Sheet1").AutoFilterMode = False
    For Each rName In rngUniques
        Set ws = Nothing
        On Error Resume Next
        Set ws = Worksheets(rName.Value)
        On Error GoTo 0
        If ws Is Nothing Then
            Worksheets.Add(After:=Sheets(Sheets.Count)).Name = rName.Value
            Sheets("Sheet1").Rows(1).Copy Cells(1, 1)
        End If
    Next rName
    For Each rName In rngUniques
        Sheets(rName.Value).UsedRange.Offset(1, 0).ClearContents
        Sheets("Sheet1").Range("A1:A" & bottomA).AutoFilter Field:=1, Criteria1:=rName
        Sheets("Sheet1").Range("A2:A" & bottomA).SpecialCells(xlCellTypeVisible).EntireRow.Copy Sheets(rName.Value).Cells(Rows.Count, "A").End(xlUp).Offset(1, 0)
        If Sheets("Sheet1").AutoFilterMode = True Then Sheets("Sheet1").AutoFilterMode = False
    Next rName
    Application.ScreenUpdating = True
 End Sub
 

ExcelNoob11

New Member
Joined
Jul 17, 2018
Messages
7
Looks like that worked.. you were much further than I was..
 
Last edited by a moderator:

ExcelNoob11

New Member
Joined
Jul 17, 2018
Messages
7
Was able to follow most of it except here:

Code:
[COLOR=#333333]Sheets(rName.Value).UsedRange.Offset(1, 0).ClearContents[/COLOR]

Are you just removing the column headers?
 

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
9,598
That line of code clears everything except the headers. This allows you to change or update the data in Sheet1 and then when you run the macro again, Sheet2 will be populated with all the new data.
 

Watch MrExcel Video

Forum statistics

Threads
1,109,533
Messages
5,529,401
Members
409,871
Latest member
i1patrick
Top