Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Counting Cells According to Case.

Counting Cells According to Case

Written by Allen Wyatt (last updated November 1, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


If you are using Excel to analyze a group of cells containing text, you may want to determine the number of cells that contain uppercase, the number that contain lowercase, and the number that contain mixed case. There are two ways you can approach this task: Using a regular worksheet formula or defining your own user-defined function.

If the text you want to evaluate is in column A, starting at cell A1, you could use the following formula in cell B1:

=IF(A1>"",IF(EXACT(UPPER(A1),A1),"Upper",
IF(EXACT(LOWER(A1),A1),"Lower","Mixed")),"")

The formula checks to see if there is anything in A1. If there is, then it uses the EXACT function to compare the contents to various conversions of the cell's contents. The formula returns an empty string if cell A1 is empty or the words Upper, Lower, or Mixed.

Copy the formula down column B as far as you need to, and then you can use the following type of formula to determine the count:

=COUNTIF(B:B,"Upper")

To find the count of lowercase or mixed-case cells, replace "Upper" with "Lower" or "Mixed".

Obviously, using formulas in this manner involves adding a column to your worksheet. There is another formula approach you can use that doesn't involve the use of an intermediate column in this manner. Consider the following formula, which returns the number of cells in the range A1:A100 that contain only uppercase letters:

=SUMPRODUCT(--(EXACT(A1:A100,UPPER(A1:A100))),--(A1:A100<>""))

A variation on this formula can be used to return the number of lowercase cells. The only thing that is changed in the following is the use of the LOWER function instead of the UPPER function:

=SUMPRODUCT(--(EXACT(A1:A100,LOWER(A1:A100))),--(A1:A100<>""))

To determine cells containing mixed case, you need to come up with a mix of the two SUMPRODUCT-based formulas:

=SUMPRODUCT(--(NOT(EXACT(A1:A100,UPPER(A1:A100)))),--
(NOT(EXACT(A1:A100,LOWER(A1:A100)))),--(A1:A100<>""))

There are some drawbacks to these formulas, drawbacks that aren't evident in the earlier formulas. First, if a cell contains a numeric value, then these formulas could count the cell as uppercase. Second, if a cell contains an error value, then the formula returns an error.

If you have the need to count case quite often, then you would probably be better served by creating a user-defined function that does the counting for you. There are many ways that such a function could be written, but the general guidelines are the following:

  • Step through each cell of a range
  • Determine if the cell is upper, lower, or mixed case
  • Increment some counter
  • Return a value

The following macro is one example of how the above can be implemented:

Function CountCase(rng As Range, sCase As String) As Long
    Dim vValue
    Dim lUpper As Long
    Dim lMixed As Long
    Dim lLower As Long
    Dim rCell As Range
    lUpper = 0
    lLower = 0
    lMixed = 0

    For Each rCell In rng
        If Not IsError(rCell.Value) Then
            vValue = rCell.Value
            If VarType(vValue) = vbString _
                And Trim(vValue) <> "" Then
                If vValue = UCase(vValue) Then
                    lUpper = lUpper + 1
                ElseIf vValue = LCase(vValue) Then
                    lLower = lLower + 1
                Else
                    lMixed = lMixed + 1
                End If
            End If
        End If
    Next
    Select Case UCase(sCase)
        Case "U"
            CountCase = lUpper
        Case "L"
            CountCase = lLower
        Case "M"
            CountCase = lMixed
        Case Else
            CountCase = CVErr(xlErrValue)
    End Select
End Function

Determining if a cell is upper, lower, or mixed case is obviously the crux of a macro such as this. Making such a determination uses the same process as was done in the worksheet formulas: compare the contents of the cell to the uppercase or lowercase conversion of those contents. In this macro the value of the cell (vValue) is compared to vValue transformed with either the UCase or LCase function.

The function also ignores cells that it doesn't make sense to evaluate. It ignores cells containing numeric values, Boolean values, error values, empty cells, and cells that contain only spaces. If a numeric value is formatted as text, then the function counts that cell as uppercase. To use this user-defined function, use a formula such as the following in your worksheet:

=COUNTCASE(A1:A100, "L")

For the first argument you use the range you want evaluated. The second argument is a single character—L, M, or U—indicating which count you want returned. If you use some other value for the second argument, then the function returns an error.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10593) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Counting Cells According to Case.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Removing Duplicate Rows

Too much data in your worksheet? Does too much of that data duplicate other data? Here's how to get rid of the duplicates ...

Discover More

Adjusting Space Before

If you need to adjust the space that appears before a paragraph, there are several ways you can approach the adjustment. ...

Discover More

Changing Chart Location

Charts can either be embedded in a worksheet or take up an entire sheet by themselves. Changing from one type of chart to ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Finding the Smallest Even Value

When processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...

Discover More

Criteria-Based Counting in a Filtered Column

The filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...

Discover More

Combining Numbers and Text in a Cell

There are times when it can be beneficial to combine both numbers and text in the same cell. This can be easily done ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two more than 7?

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


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.