G
Gasbag
I am trying to count the number of cells in a row that contain one or more of
three letters?
three letters?
Rick Rothstein said:You can simplify your function like this...
Function CountChr(Rng As Range, C1 As String, _
C2 As String, C3 As String) As Long
Dim C As Range
For Each C In Rng
If C.Value Like "*[" & C1 & C2 & C3 & "]*" Then CountChr = CountChr + 1
Next
End Function
Note I shortened the name of your function and some of your argument names
in order to prevent newsreaders from word-wrapping the long If-Then
statement.
--
Rick (MVP - Excel)
Mike H said:Someone must be able to do better than this
call with
=CountChar(B2:E2,"a","b","c")
Function CountChar(rng As Range, ch1 As String, ch2 As String, ch3 As
String) As Long
For Each c In rng
If InStr(UCase(c.Value), UCase(ch1)) Then CountChar = CountChar + 1
If InStr(UCase(c.Value), UCase(ch2)) Then CountChar = CountChar + 1
If InStr(UCase(c.Value), UCase(ch3)) Then CountChar = CountChar + 1
Next
End Function
Mike
Rick Rothstein said:You can simplify your function like this...
Function CountChr(Rng As Range, C1 As String, _
C2 As String, C3 As String) As Long
Dim C As Range
For Each C In Rng
If C.Value Like "*[" & C1 & C2 & C3 & "]*" Then CountChr = CountChr + 1
Next
End Function
Note I shortened the name of your function and some of your argument names
in order to prevent newsreaders from word-wrapping the long If-Then
statement.
--
Rick (MVP - Excel)
Mike H said:Someone must be able to do better than this
call with
=CountChar(B2:E2,"a","b","c")
Function CountChar(rng As Range, ch1 As String, ch2 As String, ch3 As
String) As Long
For Each c In rng
If InStr(UCase(c.Value), UCase(ch1)) Then CountChar = CountChar + 1
If InStr(UCase(c.Value), UCase(ch2)) Then CountChar = CountChar + 1
If InStr(UCase(c.Value), UCase(ch3)) Then CountChar = CountChar + 1
Next
End Function
Mike
I am trying to count the number of cells in a row that contain one or more of
three letters?
Gasbag said:I am trying to count the number of cells in a row that contain one or more of
three letters?
....Rick Rothstein said:You can simplify your function like this...
Function CountChr(Rng As Range, C1 As String, _
C2 As String, C3 As String) As Long
Dim C As Range
For Each C In Rng
If C.Value Like "*[" & C1 & C2 & C3 & "]*" Then CountChr = CountChr + 1
Next
End Function
....Rick Rothstein said:You can simplify your function like this...
Function CountChr(Rng As Range, C1 As String, _
C2 As String, C3 As String) As Long
Dim C As Range
For Each C In Rng
If C.Value Like "*[" & C1 & C2 & C3 & "]*" Then CountChr = CountChr + 1
Next
End Function
Rick Rothstein said:I like this idea better than my paramarray suggestion; however, I would
change your function slightly so the user would not have to know the syntax
of the Like operator...
Function Foo(A As Variant, P As String) As Double
Dim X As Variant
If Not TypeOf A Is Range And Not IsArray(A) Then A = Array(A)
For Each X In A
If X Like "*[" & P & "]*" Then Foo = Foo + 1
Next X
End Function
With this variation, all the user has to do is call the function like
this...
=Foo(A11,"agm")
--
Rick (MVP - Excel)
...Rick Rothstein said:You can simplify your function like this...
Function CountChr(Rng As Range, C1 As String, _
C2 As String, C3 As String) As Long
Dim C As Range
For Each C In Rng
If C.Value Like "*[" & C1 & C2 & C3 & "]*" Then CountChr = CountChr + 1
Next
End Function
Or make it general. Like
Function foo(a As Variant, p As String) As Double
Dim x As Variant
If Not TypeOf a Is Range And Not IsArray(a) Then a = Array(a)
For Each x In a
If x Like p Then foo = foo + 1
Next x
End Function
which could be used in formulas like
=foo(A11,"*[agm]*")
This would allow counting any valid LIKE pattern.
....Rick Rothstein said:I like this idea better than my paramarray suggestion; however, I would
change your function slightly so the user would not have to know the syntax
of the Like operator...
....T. Valko said:It also counts cells that are numeric:
gmail...10...AAA...<empty>...3M
If there might be both text and numbers then you need to add a test for
text:
=SUMPRODUCT(--(MMULT({1,1,1},--(SUBSTITUTE(LOWER(A11),
{"a";"g";"m"},"")=A11))<3),--(ISTEXT(A1
1)))