Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Counting All Characters

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Counting All Characters.

When you work with worksheets—particularly those from other people—you may be looking for a way count the number of characters in a workbook. The following macro is very handy in that regard. It counts the number of characters in an entire workbook, including any characters in any text boxes inserted in the various worksheets.

Sub CountCharacters()
    Dim wks As Worksheet
    Dim rng As Range
    Dim rCell As Range
    Dim shp As Shape

    Dim bPossibleError As Boolean
    Dim bSkipMe As Boolean

    Dim lTotal As Long
    Dim lTotal2 As Long
    Dim lConstants As Long
    Dim lFormulas As Long
    Dim lFormulaValues As Long
    Dim lTxtBox As Long
    Dim sMsg As String

    On Error GoTo ErrHandler
    Application.ScreenUpdating = False

    lTotal = 0
    lTotal2 = 0
    lConstants = 0
    lFormulas = 0
    lFormulaValues = 0
    lTxtBox = 0
    bPossibleError = False
    bSkipMe = False
    sMsg = ""

    For Each wks In ActiveWorkbook.Worksheets
        ' Count characters in text boxes
        For Each shp In wks.Shapes
            If TypeName(shp) <> "GroupObject" Then
                lTxtBox = lTxtBox + shp.TextFrame.Characters.Count
            End If
        Next shp

        ' Count characters in cells containing constants
        bPossibleError = True
        Set rng = wks.UsedRange.SpecialCells(xlCellTypeConstants)
        If bSkipMe Then
            bSkipMe = False
        Else
            For Each rCell In rng
                lConstants = lConstants + Len(rCell.Value)
            Next rCell
        End If

        ' Count characters in cells containing formulas
        bPossibleError = True
        Set rng = wks.UsedRange.SpecialCells(xlCellTypeFormulas)
        If bSkipMe Then
            bSkipMe = False
        Else
            For Each rCell In rng
                lFormulaValues = lFormulaValues + Len(rCell.Value)
                lFormulas = lFormulas + Len(rCell.Formula)
            Next rCell
        End If
    Next wks

    sMsg = Format(lTxtBox, "#,##0") & _
      " Characters in text boxes" & vbCrLf
    sMsg = sMsg & Format(lConstants, "#,##0") & _
      " Characters in constants" & vbCrLf & vbCrLf

    lTotal = lTxtBox + lConstants

    sMsg = sMsg & Format(lTotal, "#,##0") & _
      " Total characters (as constants)" & vbCrLf & vbCrLf

    sMsg = sMsg & Format(lFormulaValues, "#,##0") & _
      " Characters in formulas (as values)" & vbCrLf
    sMsg = sMsg & Format(lFormulas, "#,##0") & _
      " Characters in formulas (as formulas)" & vbCrLf & vbCrLf

    lTotal2 = lTotal + lFormulas
    lTotal = lTotal + lFormulaValues

    sMsg = sMsg & Format(lTotal, "#,##0") & _
      " Total characters (with formulas as values)" & vbCrLf
    sMsg = sMsg & Format(lTotal2, "#,##0") & _
      " Total characters (with formulas as formulas)"

    MsgBox Prompt:=sMsg, Title:="Character count"

ExitHandler:
    Application.ScreenUpdating = True
    Exit Sub

ErrHandler:
    If bPossibleError And Err.Number = 1004 Then
        bPossibleError = False
        bSkipMe = True
        Resume Next
    Else
        MsgBox Err.Number & ": " & Err.Description
        Resume ExitHandler
    End If
End Sub

The macro may seem quite long, but it is very well structured in exactly what it does. First, it looks through all the text boxes in a worksheet. If they are not grouped (you cannot count characters in grouped text boxes), then the characters in them are tallied up. Then the macro tallies up the characters in cells containing constants. Finally, it counts all the characters used in cells containing formulas. The balance of the macro is used to present the information in a message box.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2284) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Counting All Characters.

Related Tips:

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.