fabiogiallo

New Member
Joined
Mar 1, 2018
Messages
6
Good afternoon,
i am using the code below to copy some data from a "master" sheet, selected using a filter, to another "Bp" sheet.
What i need to do is:
apply filters at 2nd, 3rd, 4th columns, then the next column (5th) has to be filtered to remove empty cell, select the data (they increase day by day) and paste them to a new column in Bp sheet. Same procedure for the following colums: filter to eliminate empty cells, select all, copy and paste to another column in to next column in Bp sheet and so on.

The code is working but i was wondering if there is better way to write the code and make the worksheet faster and lighter.
Thank you.

Code:
Sub BP1andBP2_6I6N()
'
' BP1andBP2_6I6N Macro
'


    Application.ScreenUpdating = False
    ActiveSheet.Range("$A$3:$AR$30002").AutoFilter Field:=2, Criteria1:=Array( _
        "Bp1", "Bp1c", "Bp1d", "Bp2"), _
        Operator:=xlFilterValues
    ActiveSheet.Range("$A$3:$AR$30002").AutoFilter Field:=3, Criteria1:= _
        "class 6"
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=4, Criteria1:="<>"
    Range("D4:E30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("A7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=4
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=6, Criteria1:="<>"
    Range("F04:G30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("C7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=6
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=8, Criteria1:="<>"
    Range("H04:K30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("E7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=8
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=12, Criteria1:="<>"
    Range("L04:N30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("I7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=12
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=15, Criteria1:="<>"
    Range("O4:Q30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("L7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=15
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=18, Criteria1:="<>"
    Range("R4:S30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("O7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=18
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=24, Criteria1:="<>"
    Range("X4:Y30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("U7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=24
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=26, Criteria1:="<>"
    Range("Z4:AA30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("W7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=26
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=28, Criteria1:="<>"
    Range("AB4:AC30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("Y7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=28
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=30, Criteria1:="<>"
    Range("AD4:AG30002").Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("AA7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=30
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=34, Criteria1:="<>"
    Range("AH4:AG30002").Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("AE7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=34
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=37, Criteria1:="<>"
    Range("AK4:AL30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("AH7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=37
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=39, Criteria1:="<>"
    Range("AM1904:AN1904").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("AJ7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=39
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=41, Criteria1:="<>"
    Range("AO4:AP30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("AL7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=41
    ActiveSheet.Range("$A$3:$AP$30002").AutoFilter Field:=43, Criteria1:="<>"
    Range("AQ4:AR30002").Select
    Range(Selection, Selection.End(xlDown)).Select
    Application.CutCopyMode = False
    Selection.Copy
    Sheets("BP1 and BP2 6I 6N").Select
    Range("AN7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Sheets("master").Select
    ActiveSheet.ShowAllData
    Range("A4").Select
    Sheets("BP1 and BP2 6I 6N").Select
    Range("A4").Select
    Application.ScreenUpdating = True
End Sub
 
Last edited by a moderator:

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Hi & welcome to the board.
Try this
Code:
Sub BP1andBP2_6I6N()

   Dim MastWs As Worksheet
   Dim BpWs As Worksheet
   Dim Ary As Variant
   Dim i As Long
   Dim UsdRws As Long
   
Application.ScreenUpdating = False
 
   Ary = Split("4|0|6|2|8|4|12|3|15|3|18|2|24|2|26|2|28|2|30|4|34|2|37|2|39|2|41|2|43|2", "|")
   
   Set MastWs = Sheets("Master")
   Set BpWs = Sheets("BP1 and BP2 6I 6N")
   UsdRws = MastWs.Cells.Find("*", , , , xlByRows, xlPrevious, , , False).Row
   
   With MastWs
      If .AutoFilterMode Then .AutoFilterMode = False
      .Range("A3:AR" & UsdRws).AutoFilter 2, Array("Bp1", "Bp1c", "Bp1d", "Bp2"), xlFilterValues
      .Range("A3:AR" & UsdRws).AutoFilter 3, "class 6"
      .Range("A3:AR" & UsdRws).AutoFilter 4, "<>"
      .Range("D4:E" & UsdRws).Copy
      BpWs.Range("A7").PasteSpecial Paste:=xlPasteValues
   
      For i = 2 To UBound(Ary) Step 2
         .Range("A3:AR" & UsdRws).AutoFilter Ary(i - 2)
         .Range("A3:AR" & UsdRws).AutoFilter Ary(i), "<>"
         .Cells(4, CLng(Ary(i))).Resize(UsdRws, CLng(Ary(i + 1))).Copy
         BpWs.Cells(7, Columns.Count).End(xlToLeft).Offset(, 1).PasteSpecial Paste:=xlPasteValues
      Next i
      .AutoFilterMode = False
   End With
   BpWs.Select
   Range("A4").Select
Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,874
Messages
6,122,034
Members
449,061
Latest member
TheRealJoaquin

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