XL: Counting Occurrence of a Character in SelectionLast reviewed: February 2, 1998Article ID: Q89794 |
The information in this article applies to:
SUMMARYIn Microsoft Excel, you can use a macro to count the occurrences of a specific character in a cell, or range of cells. You can also use a formula to accomplish the task.
MORE INFORMATIONMicrosoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/refguide/default.asp Sample Visual Basic ProcedureThe following Visual Basic procedure prompts you for a character (or characters), then searches through the currently selected cell, or range of cells, and displays a message box showing the total number of occurrences of that character or character string. This works for all alphanumeric characters.
Dim Count As Integer Dim Target As String Dim Cell As Object Dim N As Integer Sub Target_Count() Count = 0 Target = InputBox("character(s) to find?") If Target = "" Then GoTo Done For Each Cell In Selection N = InStr(1, cell.Value, target) While N <> 0 Count = count + 1 N = InStr(n + 1, cell.Value, target) Wend Next Cell MsgBox count & " Occurrences of " & target Done: End Sub Microsoft Excel 4.0 MacroThe following macro example prompts you for a character, then searches through the currently selected cell, or range of cells, and displays a message box showing the total number of occurrences of that character. This works for all alphanumeric characters.
A1 : count=0 A2 : target=INPUT("Enter character to count: ",2) A3 : =IF(or(target="",target=false),HALT()) A4 : = FOR.CELL("TheCell") A5 : = FOR("counter",1,LEN(TheCell)) A6 : = IF(MID(TheCell,counter,1)=target) A7 : count=count+1 A8 : = END.IF() A9 : = NEXT() A10: =NEXT() A11: =ALERT("Occurrences of "&target&": "&count) A12: =RETURN()If you prefer not to use a macro, use the following formula:
{=SUM(LEN(range)-LEN(SUBSTITUTE(range,"a","")))}where "range" is the range in question, and "a" is replaced by the character you want to count. If you are concerned about a single cell, this could be simplified to:
=LEN(range)-LEN(SUBSTITUTE(range,"a",""))You can also create a version which will count the number of occurrences of any string within the range using the following variation of the formula:
{=SUM(LEN(range)-LEN(SUBSTITUTE(range,"text","")))/LEN("text")}and replace "text" with the string that you want to count.
REFERENCESFor additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:
ARTICLE-ID: Q163435 TITLE : VBA: Programming Resources for Visual Basic for Applications |
Additional query words:
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |