+ Reply to Thread
Results 1 to 10 of 10

Trying to find a formula that QUICKLY counts errors, formula or results, on a SS

Hybrid View

  1. #1
    Registered User
    Join Date
    11-09-2007
    Posts
    42

    Question Trying to find a formula that QUICKLY counts errors, formula or results, on a SS

    I am trying to just count errors in a defind range on my spreadsheet. I tried using an array formula but it killed the processing time. I then tried a UDF, shown below, but it also kills the processing time because it runs more than once when doing a standard calculation. Is there a way to set the formula to only run at the end of a calc cycle?

    Function CountErrors()
    Dim rng, c As Range, e As Integer
    
    Set rng = ActiveSheet.UsedRange
        For Each c In rng
            If InStr(1, c.Formula, "#REF!") Or IsError(c) Then
                CountErrors = CountErrors + 1
            End If
        Next c
    End Function
    Thanks!
    Last edited by Uziel; 03-17-2010 at 04:11 PM. Reason: shg told me to :)

  2. #2
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Counting Errors

    Please take a few minutes to read the forum rules, and then edit your post to add CODE tags.
    Entia non sunt multiplicanda sine necessitate

  3. #3
    Forum Expert sweep's Avatar
    Join Date
    04-03-2007
    Location
    Great Sankey, Warrington, UK
    MS-Off Ver
    2003 / 2007 / 2010 / 2016 / 365
    Posts
    3,454

    Re: Counting Errors

    Hi,

    A UDF will slow you down a touch. How about

    =SUMPRODUCT((ISERROR(range))*1)
    Rule 1: Never merge cells
    Rule 2: See rule 1

    "Tomorrow I'm going to be famous. All I need is a tennis racket and a hat".

  4. #4
    Registered User
    Join Date
    11-09-2007
    Posts
    42

    Re: Counting Errors

    I think that formula has the same problem as the UDF. It takes 2.5 seconds to calculate without the formula. I added the formula, hit calculate, and stopped the calculation when it was at 30% done and 30 seconds into the calculation.... Excel seems to repeatedly calculate both formulas where it only needs to be done once...at the end.

    Thoughts?

  5. #5
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Counting Errors

    Thoughts?
    I think you ought to read my last post.

  6. #6
    Registered User
    Join Date
    11-09-2007
    Posts
    42

    Re: Counting Errors

    Sorry shg, I did not even see your post. I will do that right now.

  7. #7
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Trying to find a formula that QUICKLY counts errors, formula or results, on a SS

    Your title was fine. What I asked is that you add CODE tags.

  8. #8
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Trying to find a formula that QUICKLY counts errors, formula or results, on a SS

    Third time's the charm.

    Try this; code goes in the Sheet module:
    Private Sub Worksheet_Calculate()
        Dim nErr As Long
        
        On Error Resume Next
        nErr = Me.UsedRange.SpecialCells(xlCellTypeFormulas, xlErrors).Count
        
        Application.EnableEvents = False
        Range("A1").Value = "Errors: " & nErr   ' change range as desired
        Application.EnableEvents = True
    End Sub

  9. #9
    Registered User
    Join Date
    11-09-2007
    Posts
    42

    Re: Trying to find a formula that QUICKLY counts errors, formula or results, on a SS

    Thank you sir. Just off that one bit of code a learned a NUMBER of new things!

    I apologize about the trouble with the post. I am now officially trained.

  10. #10
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Trying to find a formula that QUICKLY counts errors, formula or results, on a SS

    Did you read the part about marking threads as Solved?

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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