+ Reply to Thread
Results 1 to 2 of 2

Advanced Filter Error

Hybrid View

  1. #1
    Registered User
    Join Date
    05-16-2012
    Location
    Atlanta, GA
    MS-Off Ver
    Excel 2007
    Posts
    63

    Advanced Filter Error

    For some reason I am receiving the following error when trying to write an advanced filter "Method 'Range' of object '_Global' Failed"
    Weird thing is I have virtually the same code(the dynamic range and advanced filter part) in a another macro with just different names and it works fine there. The purpose of the filter is to display on the FICA OOBs sheet only items in the WT column of /403, /404, /405, /406 and the FICA OOBs column with a value < 0 using the criteria on the Filter_Criteria sheet. The range of the filter is a named Range I created based on the FICA OOBs sheet.

    
    Sub FICA_OOB_EE_SS_Table()
    '
    'Verifies that all EE SS FICA wagetypes are being calculated correctly
    '
    
    'Prevent screen updating
    Application.ScreenUpdating = False
    
    Call DeleteNamedRanges
    Call FICA_Filter_Criteria_Sheet
    
    'Create copy of DAT sheet
       Sheets("DAT").Copy After:=Sheets("DAT")
        ActiveSheet.Name = "FICA OOBs"
        
       
    'enter formula in column
    Sheets("FICA OOBs").Select
    Columns("N:N").Formula = "=J1*FICA_Rates!$B$2-F1"
    
    Range("N1") = ""
    Range("N2") = "FICA OOBs"
    
    'Create Dynamic named range
        ActiveWorkbook.Names.Add Name:="RANGE_OOBs", RefersToR1C1:= _
            "=OFFSET(FICA OOBs!R2C1,0,0,COUNTA(FICA OOBs!C2),14)"
        ActiveWorkbook.Names("RANGE_OOBs").Comment = ""
        
    'Apply advanced filter
    Range("RANGE_OOBs").AdvancedFilter Action:=xlFilterInPlace, CriteriaRange:= _
            Sheets("Filter_Criteria").Range("A1:B5"), Unique:=False                                                  'debugger points to this line
        Range("A4").Select
    
        
    Rows(2).Font.Bold = True
    
    'autofit column width
     Columns("N:N").EntireColumn.AutoFit
    
    
    Range("N1") = ""
    Range("N2") = "FICA OOBs"
    
    'Hide Columns
      Sheets("FICA OOBs").Select
      Range("C1,G1:I1,K1:M1").EntireColumn.Select
        Selection.EntireColumn.Hidden = True
           
    End Sub
    
    Sub FICA_Filter_Criteria_Sheet()
    Worksheets.Add(After:=Worksheets(Worksheets.Count)).Name = "Filter_Criteria"
    ActiveCell.FormulaR1C1 = "Filter_Criteria"
        Range("A1") = "WT"
        Range("A2") = "/403"
        Range("A3") = "/404"
        Range("A4") = "/405"
        Range("A5") = "/406"
        Range("B1") = "FICA OOBs"
        Range("B2:B5") = "<0"
    
    Rows(1).Font.Bold = True
    
    'autofit column width
     Columns("A:B").EntireColumn.AutoFit
    
    
    End Sub
    Thanks for nay help,

    Craig
    Last edited by csh8428; 09-06-2012 at 03:13 PM.

  2. #2
    Forum Expert jaslake's Avatar
    Join Date
    02-21-2009
    Location
    Atwood Lake in Mid NE Ohio...look it up.
    MS-Off Ver
    Excel 2010 2019
    Posts
    12,749

    Re: Advanced Filter Error

    Hi csh8428
    Can't test your code...no workbook attached. This line of code will raise a #REF error in the Named Range
     "=OFFSET(FICA OOBs!R2C1,0,0,COUNTA(FICA OOBs!C2),14)"
    If you have spaces in the Worksheet Name when naming ranges you need to wrap the Sheet Name in single quotes
    "=OFFSET('FICA OOBs'!R2C1,0,0,COUNTA('FICA OOBs'!C2),14)"
    John

    If you have issues with Code I've provided, I appreciate your feedback.

    In the event Code provided resolves your issue, please mark your Thread as SOLVED.

    If you're satisfied by any members response to your issue please use the star icon at the lower left of their post.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1