vba Countif formula on Arr

Mallesh23

Active Member
Joined
Feb 4, 2009
Messages
275
Office Version
2010
Platform
Windows
Hi Team,

Need your help , I am trying to use countif formula on array value, but its not working.

MsgBox WorksheetFunction.CountIf(arr, "Completed") Why this line not working.
MsgBox WorksheetFunction.CountA(arr) this line gives result.

Sub Test()

Dim arr As Variant
arr = Range("A2:a30").Value

Range("b5").FormulaR1C1 = "=COUNTIF(R2C1:R30C1,""Completed"")" ' This line works.
MsgBox WorksheetFunction.CountIf(arr, "Completed") not working

End Sub

Thanks
mg
 

Some videos you may like

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,092
CountIf() does not accept arrays. Try pass it a Range object instead...

VBA Code:
Sub Test()

    Dim rng As Range
    Set rng = Range("A2:A30")
   
    Range("b5").FormulaR1C1 = "=COUNTIF(R2C1:R30C1,""Completed"")" ' This line works.
   
    MsgBox WorksheetFunction.CountIf(rng, "Completed")

End Sub
Hope this helps!
 

Mallesh23

Active Member
Joined
Feb 4, 2009
Messages
275
Office Version
2010
Platform
Windows
Hi Dominic,

Thanks for your help, I have below question.

is there a other way to count specific values from Array.
Can't we apply any formula on Data stored in Array.

Regards,
mg
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,092
is there a other way to count specific values from Array.
One way would be to simply loop through each element of the array, and increment a count for each one that meets the criteria. However, here's another way that uses the Filter function to filter the array for the specified criteria, and then uses the CountA method to return a count of elements in the filtered array.

Code:
Sub Test()

    Dim arr As Variant
    arr = Range("A2:A30").Value
    
    Dim filteredArray() As String
    filteredArray = VBA.Filter(Application.Transpose(arr), "Completed", True)
    
    If UBound(filteredArray) <> -1 Then
        MsgBox Application.CountA(filteredArray)
    Else
        MsgBox "No record found!", vbExclamation
    End If

End Sub
Can't we apply any formula on Data stored in Array.
The method will depend on the data type, and what it is that you want to do.
 

Mallesh23

Active Member
Joined
Feb 4, 2009
Messages
275
Office Version
2010
Platform
Windows
Hi Dominic,

Thanks for your help, it worked !!!

(y)
Regards,
mg
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,092
You're very welcome, glad I could help, and thanks for the feedback, cheers!
 

Forum statistics

Threads
1,089,666
Messages
5,409,622
Members
403,271
Latest member
user2456

This Week's Hot Topics

Top