Page 1 of 3 123 LastLast
Results 1 to 10 of 26

Thread: Macro to check values based on certain text

  1. #1
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13

    Macro to check values based on certain text

    I have the word "Check" in Column A. Where Check appears in cloumn A I would like to determine whether the values in the same row as where "check" appears <> (not equal) to zero. This needs to be checked on all sheets, except the sheet "Consolidated"

    I have code to do this, but when running the code, I get an error message "unable to get the sum property of the worksheet function class" -the folowing code is highlighted when I click on Debug

    If Application.WorksheetFunction.Sum(myrange) <> 0 Then

    The full code is

    Code:
    Sub Check_Variance()
            Dim sh
            Dim caddress As String, lastrowSH1 As Long
            Dim startcell As Range, endcell As Range, myrange As Range
    
    
            For Each sh In Worksheets
            If UCase(sh.Name) <> "CONSOLIDATED" Then
            caddress = ""
            lastrowSH1 = Sheets(sh.Name).Range("A" & Rows.Count).End(xlUp).Row
    
            For Each cell In Sheets(sh.Name).Range("A1:A" & lastrowSH1)
            Debug.Print sh.Name
            Debug.Print cell.Value
            If UCase(cell.Value) = "CHECK" Then
            Set startcell = Sheets(sh.Name).Range("B" & cell.Row)
            Set endcell = Sheets(sh.Name).Range("Q" & cell.Row)
            Set myrange = Sheets(sh.Name).Range(startcell, endcell)
    
             If Application.WorksheetFunction.Sum(myrange) <> 0 Then
              For i = 1 To 26
               If cell.Offset(0, i) <> 0 Then
                If caddress = "" Then
                caddress = cell.Offset(0, i).Address
                Else
                caddress = caddress & ", " & cell.Offset(0, i).Address
                End If
               End If
               Next i
             End If
            End If
            Next cell
            If caddress <> "" Then
            MsgBox "Please check the following address(es) on " & sh.Name & vbNewLine & vbNewLine & caddress
            End If
            End If
            Next sh
            End Sub
    Last edited by Admin; 10-18-2012 at 07:55 AM. Reason: code tag added

  2. #2
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    @ Howard

    Please add code tags while posting codes
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  3. #3
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    Hi

    Try

    Code:
    Sub Check_Variance()
        Dim sh  As Worksheet, cCell As Range
        Dim cAddress As String, lastRowSH1 As Long, i As Long
        Dim startCell As Range, endCell As Range, myRange As Range
    
    
        For Each sh In Worksheets
            If UCase(sh.Name) <> "CONSOLIDATED" Then
                cAddress = ""
                
                With sh
                    lastRowSH1 = .Range("A" & .Rows.Count).End(xlUp).Row
                    For Each cCell In .Range("A1:A" & lastRowSH1)
                        Debug.Print sh.Name
                        Debug.Print cCell.Value
                        If UCase(cCell.Value) = "CHECK" Then
                            Set startCell = .Range("B" & cCell.Row)
                            Set endCell = .Range("Q" & cCell.Row)
                            Set myRange = .Range(startCell, endCell)
        
                            If Application.WorksheetFunction.Sum(myRange) <> 0 Then
                                For i = 1 To 26
                                    If cCell.Offset(0, i) <> 0 Then
                                        If cAddress = "" Then
                                            cAddress = cCell.Offset(0, i).Address
                                        Else
                                            cAddress = cAddress & ", " & cCell.Offset(0, i).Address
                                        End If
                                    End If
                                Next i
                            End If
                        End If
                    Next cCell
                    If cAddress <> "" Then
                        MsgBox "Please check the following address(es) on " & sh.Name & vbNewLine & vbNewLine & cAddress
                    End If
                End With
            End If
        Next sh
    End Sub
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  4. #4
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13
    Thanks for the reply. I still get "unable to get the sum property of the worksheet function class" -the folowing code is highlighted when I click on Debug

    HTML Code:
    If Application.WorksheetFunction.Sum(myrange) <> 0 Then
    Your assistance is most appreciated

  5. #5
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    Hi

    Is there any error values in the sum range ?
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  6. #6
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13
    Quote Originally Posted by Admin View Post
    Hi

    Is there any error values in the sum range ?
    There are two #N/A's, which I think is causing the problem. Would it be possible to incorporate this into the macro i.e if the valiue is <> 0 or there is an error , the user must be advised via the message box

  7. #7
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    Hi

    Replace the error line with

    Code:
    If Evaluate("sumif(" & myRange.Address(external:=1) & ",{"">0"",""<0""})") <> 0 Then
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  8. #8
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13
    Quote Originally Posted by Admin View Post
    Hi

    Replace the error line with

    Code:
    If Evaluate("sumif(" & myRange.Address(external:=1) & ",{"">0"",""<0""})") <> 0 Then
    Thanks for the help-code works perfectly, much appreciated. I need one small amendment. Some the values in the same row as check are for very small eg 0.0001 or (0.0001). I would like the code amended so that where the variance start is more than three decimals plances, it must be ignored

  9. #9
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    Not sure I understood you correctly. Can you provide an example row ?
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  10. #10
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13
    Quote Originally Posted by Admin View Post
    Not sure I understood you correctly. Can you provide an example row ?
    Attached please find row of sample data. Where the variance is very small i.e tolerance showing more than three decimal places it must be ignored as tolerance is minute

    Your assistance in this regard is most appreciated
    Attached Files Attached Files

Similar Threads

  1. Sum values based on multiple criteria
    By Jorrg1 in forum Excel Help
    Replies: 8
    Last Post: 01-07-2013, 03:04 PM
  2. Replies: 10
    Last Post: 12-10-2012, 11:28 PM
  3. Offset based on Values in Column E
    By mrmmickle1 in forum Excel Help
    Replies: 7
    Last Post: 12-04-2012, 10:06 AM
  4. Macro to clear data based on color fill
    By Howardc in forum Excel Help
    Replies: 7
    Last Post: 12-03-2012, 09:25 AM
  5. Loop and Check For Values In Entire Column in Excel
    By Jeff5019 in forum Excel Help
    Replies: 3
    Last Post: 05-01-2012, 10:34 PM

Posting Permissions

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