Excel macro for multiple filters (in a table)

gomes123

New Member
Joined
Jun 16, 2021
Messages
39
Office Version
  1. 2007
Platform
  1. Windows
I have a table starting in row 2 (heading in row 2, data starts in row 3), and I'd like to filter in priority:

In column I - select the criteria UP, DOWN, LEFT, RIGHT,
Then column J - sort largest to smallest
Then filter out #DIV/0! from column J
Then back to column I - sort Z-A (descending)

The macro seems to work except to sort from Z-A (descending), and the macro seems "messy" and I'm wondering if it is possibly to consolidate all the filters in a neater code? Also, is it better to use ".Range("$A$2:L" & .Cells(Rows.Count, "A").End(xlUp).Row)" or "ActiveSheet.Range("$A$2:$L$" & LastRow2)" ?

VBA Code:
Sub Breakthrough()
    Dim ws As Worksheet
    Set ws = ThisWorkbook.Sheets("Main")
    
    Dim LastRow As Long
    LastRow = ws.Cells(ws.Rows.Count, "A").End(xlUp).Row
    
    ws.Range("C3").Formula = "=VLOOKUP(B3,'Day1'!B:D,2,0)"
    ws.Range("D3").Formula = "=E3*5"
    ws.Range("E3").Formula = "=F3*5"
    ws.Range("F3").Formula = "=G3*5"
    ws.Range("G3").Formula = "=H3*5"
    ws.Range("H3").Formula = "=K3/10"
    ws.Range("I3").Formula = "=IF(AND(E3>C3,G3>E3,F3>D3,H3>F3),""UP"",IF(AND(C3>E3,E3>G3,D3>F3,F3>H3),""DOWN"",IF(AND(E3>C3,G3>E3,D3>F3,F3>H3),""RIGHT"",IF(AND(C3>E3,E3>G3,F3>D3,H3>F3),""LEFT"",""NO""))))"
    ws.Range("J3").Formula = "=H3/D3"
    ws.Range("K3").Formula = "=VLOOKUP(B3,'t+5'!B:C,2,0)"
    ws.Range("L3").Formula = "=(K3-G3)/G3"

    Range("C3:L" & Range("A" & Rows.Count).End(xlUp).Row).FillDown
    
    Range("I2").Select
    
    Dim LastRow2 As Long
LastRow2 = Range("A" & Rows.Count).End(xlUp).Row
Selection.AutoFilter
ActiveSheet.Range("$A$2:$L$" & LastRow2).AutoFilter Field:=9, Criteria1:=Array( _
        "DOWN", "LEFT", "RIGHT", "UP"), Operator:=xlFilterValues
ActiveWorkbook.Worksheets("Main").AutoFilter.Sort.SortFields.Clear
ActiveWorkbook.Worksheets("Main").AutoFilter.Sort.SortFields.Add Key:=Range( _
"J2:J" & LastRow2), SortOn:=xlSortOnValues, Order:=xlDescending, DataOption:= _
xlSortNormal


With ActiveSheet.AutoFilter.Sort
.Header = xlYes
.MatchCase = False
.Orientation = xlTopToBottom
.SortMethod = xlPinYin
.Apply
End With

With ActiveSheet
  .Range("$A$2:L" & .Cells(Rows.Count, "A").End(xlUp).Row).AutoFilter 10, "<>#DIV/0!"
End With

End Sub
 
Could you share a copy your data here? Thank You
Thanks, I'll try provide a sample of the data and post it here.
And let us know if the Activesheet & Main are the same sheet ?
Thank you, yes the Activesheet & "Main" worksheet is the same.

Is it better to use ActiveWorkbook.Worksheets("Main") or With ActiveSheet?
 
Upvote 0
Is it better to use ActiveWorkbook.Worksheets("Main") or With ActiveSheet?
It depends on whether the Sheet is the ActiveSheet and whether it is always to be the case. My preference is to be explicit fully qualify the sheet it is working on.
Whatever method you choose you want to stay consistent. The current code uses 5 different ways of addressing the sheet.
  • ws
  • ThisWorkbook.Sheets("Main")
  • ActiveWorkbook.Sheets("Main")
  • ActiveSheet
  • Range or Selection both of which assume the ActiveSheet
On a copy of your workbook try the code below.
Note: Your sort is probably going astray because you are sorting after filtering which only sorts the visible rows.

VBA Code:
Sub Breakthrough_v02()
    Dim ws As Worksheet
    Set ws = ThisWorkbook.Sheets("Main")
   
    Dim LastRow As Long
   
    With ws
   
        If .FilterMode = True Then
            .ShowAllData
        End If
       
        LastRow = .Cells(.Rows.Count, "A").End(xlUp).Row
       
        .Range("C3").Formula = "=VLOOKUP(B3,'Day1'!B:D,2,0)"
        .Range("D3").Formula = "=E3*5"
        .Range("E3").Formula = "=F3*5"
        .Range("F3").Formula = "=G3*5"
        .Range("G3").Formula = "=H3*5"
        .Range("H3").Formula = "=K3/10"
        .Range("I3").Formula = "=IF(AND(E3>C3,G3>E3,F3>D3,H3>F3),""UP"",IF(AND(C3>E3,E3>G3,D3>F3,F3>H3),""DOWN"",IF(AND(E3>C3,G3>E3,D3>F3,F3>H3),""RIGHT"",IF(AND(C3>E3,E3>G3,F3>D3,H3>F3),""LEFT"",""NO""))))"
        .Range("J3").Formula = "=H3/D3"
        .Range("K3").Formula = "=VLOOKUP(B3,'t+5'!B:C,2,0)"
        .Range("L3").Formula = "=(K3-G3)/G3"
   
        .Range("C3:L" & .Range("A" & .Rows.Count).End(xlUp).Row).FillDown
   
        With .Range("$A$2:$L$" & LastRow)
            .Sort key1:=.Columns(10), _
                order1:=xlDescending, Header:=xlYes

            .AutoFilter Field:=9, _
                    Criteria1:=Array("DOWN", "LEFT", "RIGHT", "UP"), Operator:=xlFilterValues
            .AutoFilter 10, "<>#DIV/0!"
        End With
   
    End With
   
End Sub
 
Upvote 0

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