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
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
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
 
Upvote 0
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?
 
Upvote 0
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.
 
Upvote 0

Forum statistics

Threads
1,214,611
Messages
6,120,513
Members
448,967
Latest member
screechyboy79

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top