Filter based on named range cell - debug help required

F

fishy

I am trying to filter a sheet based on the named cell ("TeamData) on an
alternate sheet but keep getting a debug 'Object required' at the criteria
range. The debug recognises the value in the range as when hovering it shows
the correct text on the highlighted issue.

Detailed is the code:

Sub FilterSelection()

Sheets("Edit").Select

...AutoFilterMode =False

Columns("A:I").Select
Selection.AutoFilter
My_Range.AutoFilter Field:=1, Criteria1:="=" & Range("TeamData").Value
My_Range.AutoFilter Field:=2, Criteria1:="=" & Range("TeamData").Value

Range("A2:I500").Select
Selection.Copy
Sheets("Calculate").Select
Range("A1").Select
Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone,
SkipBlanks _
:=False, Transpose:=False
Sheets("Edit").Select

My_Range.AutoFilter Field:=2, Criteria1:="<>" & Range("TeamData").Value

Rows("2:500").Select
Application.CutCopyMode = False
Selection.Copy
Sheets("Calculate").Select
Range("A2").Select
ActiveSheet.Paste

End Sub

I am assuming there is a better way to copy and paste the selected data to
the other sheet based on what is returned but would not know where to start.

Column A is the team names, column B are the staff names but the team total
also has the team name in this column to make it easy to filter.

I have to filter the team total to the top of the page and then copy the
staff data below to make the rest of the spreadsheet work (not in this macro).

Any help would be appreciated
 
J

Joel

Autofilter is very hard to work with in a macro and also has problems in the
worksheet. Here are a few tips

1) You need a header row in front of your data otherwise you can get a
duplicate entry in the first row of data
2) In a macro you need to test if the value exists before adding a criteria
otherwise you fail
3) When copying filtered results use Specialcells method and look for
visible cells. the worksheet has specialcells hidden under the menu

Edit - GoTo - Special (most people don't knoiw this)



Sub FilterSelection()

With Sheets("Edit")

'remove autofilter is is exists
If .AutoFilterMode Then
.Cells.AutoFilter
End If

'find last row
LastRow = .Range("A" & Rows.Count).End(xlUp).Row

'add back autofilter
.Columns("A:I").AutoFilter

Data = "=" & Range("TeamData").Value
'check if data exists in column A
'autofilter will not let you add a filter for something
'that doesn't exist
Set c = .Columns("A").Find(what:=Data, _
LookIn:=xlValues, lookat:=xlWhole)
If Not c Is Nothing Then
.Columns("A:I").AutoFilter Field:=1, _
Criteria1:=Data
End If

'now check for data in column B
'use special filter method to check only visible cells
Set MyRange = .Range("B1:B" & LastRow).SpecialCells(xlCellTypeVisible)
Set c = MyRange.Find(what:=Data, _
LookIn:=xlValues, lookat:=xlWhole)
If Not c Is Nothing Then
.Columns("A:I").AutoFilter Field:=2, _
Criteria1:=Data
End If

.Range("A1:I" & LastRow).SpecialCells(xlCellTypeVisible).Copy
Sheets("Calculate").Range("A1").PasteSpecial Paste:=xlPasteValues

End With
End Sub
 
F

fishy

Thanks, whilst checking this I came across another help by Ron D Bruins which
I have been able to modify succesfully.
 
F

fishy

Details of the code:

Sub FilterTeamStats()

Dim My_Range As Range
Dim DestSh As Worksheet
Dim CalcMode As Long
Dim ViewMode As Long
Dim FilterCriteria As String
Dim CCount As Long
Dim Rng As Range

Sheets("Edit").Select

Set My_Range = Range("A2:I" & LastRow(ActiveSheet))
My_Range.Parent.Select

'Set the destination worksheet
'Note: the sheet must exist in your workbook.
Set DestSh = Sheets("Calculate")

If ActiveWorkbook.ProtectStructure = True Or _
My_Range.Parent.ProtectContents = True Then
MsgBox "Sorry, not working when the workbook or worksheet is
protected", _
vbOKOnly, "Copy to new worksheet"
Exit Sub
End If

'Change ScreenUpdating, Calculation, EnableEvents, ....
With Application
CalcMode = .Calculation
.Calculation = xlCalculationManual
.ScreenUpdating = False
.EnableEvents = False
End With
ViewMode = ActiveWindow.View
ActiveWindow.View = xlNormalView
ActiveSheet.DisplayPageBreaks = False

'Firstly, remove the AutoFilter
My_Range.Parent.AutoFilterMode = False

FilterCriteria = Range("TeamData")
My_Range.AutoFilter Field:=1, Criteria1:="=" & FilterCriteria
My_Range.AutoFilter Field:=2, Criteria1:="<>" & FilterCriteria

'Check if there are not more then 8192 areas(limit of areas that Excel
can copy)
CCount = 0
On Error Resume Next
CCount =
My_Range.Columns(1).SpecialCells(xlCellTypeVisible).Areas(1).Cells.Count
On Error GoTo 0
If CCount = 0 Then
MsgBox "There are more than 8192 areas:" _
& vbNewLine & "It is not possible to copy the visible data." _
& vbNewLine & "Tip: Sort your data before you use this macro.", _
vbOKOnly, "Copy to worksheet"
Else
'Copy the visible data and use PasteSpecial to paste to the Destsh
With My_Range.Parent.AutoFilter.Range
On Error Resume Next
' Set rng to the visible cells in My_Range without the header row
Set Rng = .Offset(1, 0).Resize(.Rows.Count - 1, .Columns.Count) _
.SpecialCells(xlCellTypeVisible)
On Error GoTo 0
If Not Rng Is Nothing Then
'Copy and paste the cells into DestSh below the existing data
Rng.Copy
With DestSh.Range("A" & LastRow(DestSh) + 1)
' Paste:=8 will copy the columnwidth in Excel 2000 and
higher
' Remove this line if you use Excel 97
.PasteSpecial Paste:=8
.PasteSpecial xlPasteValues
.PasteSpecial xlPasteFormats
Application.CutCopyMode = False
End With
'Delete the rows in the My_Range.Parent worksheet
Rng.EntireRow.Delete
End If
End With
End If

'Close AutoFilter
My_Range.Parent.AutoFilterMode = False

'Restore ScreenUpdating, Calculation, EnableEvents, ....
ActiveWindow.View = ViewMode
Application.Goto DestSh.Range("A1")
With Application
.ScreenUpdating = True
.EnableEvents = True
.Calculation = CalcMode
End With

End Sub
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top