Consulting

Results 1 to 11 of 11

Thread: Method 'Range' of object '_Worksheet' failed error

  1. #1
    VBAX Regular
    Joined
    Aug 2006
    Posts
    82
    Location

    Method 'Range' of object '_Worksheet' failed error

    I have the following code that I'm using to validate survey responses. The defined range should have no zeros, and if it does, the msgbox will appear to let the respondent know that they skipped an item or items, as well as the item number(s).

    Dim vCell As Range
    
    
    Sheets("Calculations").Range("C4:C53").Name = "val_range"
    For Each vCell In Range("val_range")
        If ActiveCell.Value = 0 Then
            msg = msg & ActiveCell.Offset(0, -2).Value & vbCr
            k = k + 1
        End If
    Next vCell
    I'm getting the error at the line

    For Each vCell In Range("val_range")
    I borrowed this code from an expert in another post while researching a different question, and only changed the particulars, so I'm not sure why it's failing. I suspect it may have to do with the fact that the sheet is initially hidden, though I'm unhiding it earlier in this procedure. I also attempted to activate the sheet first, but still get the error.

    What am I missing?

  2. #2
    VBAX Expert
    Joined
    Aug 2004
    Posts
    810
    Location
    I do believe that in order to do anything..... your sheet must be visible, therefore, make the sheet visible first.

  3. #3
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,876
    Dim vCell As Range 
    Sheets("Calculations").Range("C4:C53").Name = "val_range" 
    For Each vCell In Range("val_range") 
        If vCell.Value = 0 Then 
            msg = msg & vCell.Offset(0, -2).Value & vbCr 
            k = k + 1 
        End If 
    Next vCell
    ?
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  4. #4
    Moderator VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    You don't need to add an item to the Sheet's list of Names
    Dim vCell As Range 
    Dim ValRange As Range 
     
    Set ValRange =  Sheets("Calculations").Range("C4:C53")
    For Each vCell In ValRange
        If vCell.Value = 0 Then 
            msg = msg & vCell.Offset(0, -2).Value & vbCR
            k = k + 1 
        End If 
    Next vCell
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  5. #5
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,728
    Location
    Try

    For Each vCell In Range("val_range").Cells
    If that works, it'll be the second time today I've seen the problem.
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  6. #6
    VBAX Regular
    Joined
    Aug 2006
    Posts
    82
    Location
    Thanks all! Good responses from all and extremely helpful. Problem is solved, and I learned something new today!

  7. #7
    Knowledge Base Approver VBAX Wizard
    Joined
    Apr 2012
    Posts
    5,645
    Or:

    Sub M_snb()
      If [not(iserr(match(0,C4:C54,0)))] Then MsgBox Cells(3, 1).Offset([match(0,C4:C54,0)])
    End Sub

  8. #8
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,876
    Quote Originally Posted by snb View Post
    Or:

    Sub M_snb()
      If [not(iserr(match(0,C4:C54,0)))] Then MsgBox Cells(3, 1).Offset([match(0,C4:C54,0)])
    End Sub
    snb, it only returns the first match!

  9. #9
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,876
    …however
    MsgBox Join(Filter([transpose(IF(Calculations!C4:C53=0,Calculations!A4:A53,"¬!"))], "¬!", False), vbLf)
    or
    MsgBox Join(Filter([transpose(IF(exact(Calculations!C4:C53,0),Calculations!A4:A53,"¬!"))], "¬!", False), vbLf)
    depending on whether you want blanks to be counted as zeroes.

  10. #10
    Knowledge Base Approver VBAX Wizard
    Joined
    Apr 2012
    Posts
    5,645
    @p45cal

    As soon as you have changed the first zeror, the next one will be shown in the msgbox.

  11. #11
    Moderator VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    @ Kualjo,

    I like snb's approach of only reporting one cell at time better than one message with a list, because if there are many missing values, who can remember them all.

    However I also prefer to highlight all the cells at once to show which ones are missing so they aren't pestered with popups. This is also similar to Web Page form actions.

    Dim vCell As Range
    Dim ValRange As Range
    Missing = False
    Set ValRange = Sheets("Calculations").Range("C4:C53")
    For Each vCell In ValRange
    If vCell.Value = 0 Then
    vCell.ColorIndex = 22
    Missing = True
    End If
    Next vCell

    Add The Variable "Missing As Boolean" to the worksheet Module and add
    Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    'Removes warning color from Cell when Cell is selected
    If Not Missing Then Exit Sub
    If Target.Interior.ColorIndex = 22 Then Target.Interior.ColorIndex = xlColorIndexNone
    End Sub
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

Posting Permissions

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