Copying rows from Master sheet (sheet 1) to mulitple sheets 2-13 based on value in column D of Master

Ajones170

New Member
Joined
Jul 14, 2021
Messages
8
Office Version
  1. 365
Platform
  1. Windows
I am trying to copy rows from master sheet (sheet 1) to multiple sheets based on the value in column D.
EX. If column D value = 1577 or 1603 copy to sheet 2
If Column D value = 5047 or 6425 copy to sheet 3.
Suggestions without adding a button on each sheet????
 
Please answer my question: The data you posted in Post #3 shows that the code is in column D but does not show in which column the sheet names are located. In which column are those sheet names located in your sheet?
I don't have the sheet named in my sheet. I am giving you a header row.
In column D - Cde will contain the code that needs to be used when deciding where to move the row.
If cde = 1603 or 4995 copy data in row to sheet 2
If cde = 1573 or 6073 copy data in row to sheet 3
etc.

Data_SrcRep_DteIDCdeF_NameM_InitialL_NameAddress1Address2CityState_FullStateZipZip4Country_TxtCountry_ISOCountry_CdeFIPSCounty_NameProvPostalPhonePh_CtryCdePh_TypeEmailDOB
 
Upvote 0

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
If cde = 1603 or 4995 copy data in row to sheet 2
If cde = 1573 or 6073 copy data in row to sheet 3
This macro does what the above asks:
VBA Code:
Sub CopyRows()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    With Sheets("Sheet1")
        .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1603", Operator:=xlOr, Criteria2:="=4995"
        .AutoFilter.Range.Offset(1).Copy Sheets("Sheet2").Cells(Sheets("Sheet2").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1573", Operator:=xlOr, Criteria2:="=6073"
        .AutoFilter.Range.Offset(1).Copy Sheets("Sheet3").Cells(Sheets("Sheet3").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1").AutoFilter
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Sub CopyRows() Application.ScreenUpdating = False Dim LastRow As Long LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row With Sheets("Sheet1") .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1603", Operator:=xlOr, Criteria2:="=4995" .AutoFilter.Range.Offset(1).Copy Sheets("Sheet2").Cells(Sheets("Sheet2").Rows.Count, "A").End(xlUp).Offset(1) .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1573", Operator:=xlOr, Criteria2:="=6073" .AutoFilter.Range.Offset(1).Copy Sheets("Sheet3").Cells(Sheets("Sheet3").Rows.Count, "A").End(xlUp).Offset(1) .Range("A1").AutoFilter End With Application.ScreenUpdating = True End Sub
This is great!! One more question in the next sheet - sheet 4 can have 4 different codes. I tried following your code and adding this but it gives an error.

.Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=5015", Operator:=xlOr, Criteria2:="=5048", Operator:=xlOr, Criteria3:="=5058", Operator:=xlOr, Criteria4:="=6425"
.AutoFilter.Range.Offset(1).Copy Sheets("sheet4").Cells(Sheets("sheet4").Rows.Count, "A").End(xlUp).Offset(1)
 
Upvote 0
Autofilter limits you to only 2 criteria. If you want to use more than 2, you must define an array of values (arr) to use as the criteria and use xlfiltervalues. See the sections in red.
Rich (BB code):
Sub CopyRows()
    Application.ScreenUpdating = False
    Dim LastRow As Long, arr As Variant
    arr = Array("5015", "5048", "5058", "6425")
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    With Sheets("Sheet1")
        .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1603", Operator:=xlOr, Criteria2:="=4995"
        .AutoFilter.Range.Offset(1).Copy Sheets("Sheet2").Cells(Sheets("Sheet2").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1573", Operator:=xlOr, Criteria2:="=6073"
        .AutoFilter.Range.Offset(1).Copy Sheets("Sheet3").Cells(Sheets("Sheet3").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1:Z" & LastRow).AutoFilter 4, arr, xlFilterValues
        .AutoFilter.Range.Offset(1).Copy Sheets("sheet4").Cells(Sheets("sheet4").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1").AutoFilter
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Autofilter limits you to only 2 criteria. If you want to use more than 2, you must define an array of values (arr) to use as the criteria and use xlfiltervalues. See the sections in red.
Rich (BB code):
Sub CopyRows()
    Application.ScreenUpdating = False
    Dim LastRow As Long, arr As Variant
    arr = Array("5015", "5048", "5058", "6425")
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    With Sheets("Sheet1")
        .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1603", Operator:=xlOr, Criteria2:="=4995"
        .AutoFilter.Range.Offset(1).Copy Sheets("Sheet2").Cells(Sheets("Sheet2").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1:Z" & LastRow).AutoFilter Field:=4, Criteria1:="=1573", Operator:=xlOr, Criteria2:="=6073"
        .AutoFilter.Range.Offset(1).Copy Sheets("Sheet3").Cells(Sheets("Sheet3").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1:Z" & LastRow).AutoFilter 4, arr, xlFilterValues
        .AutoFilter.Range.Offset(1).Copy Sheets("sheet4").Cells(Sheets("sheet4").Rows.Count, "A").End(xlUp).Offset(1)
        .Range("A1").AutoFilter
    End With
    Application.ScreenUpdating = True
End Sub
Thank you!! I got it!
 
Upvote 0

Forum statistics

Threads
1,213,544
Messages
6,114,249
Members
448,556
Latest member
peterhess2002

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