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.
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:
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:
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.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
You can easily sum a series of values in Excel, but it is not so easy to sum the absolute values of each value in a ...
Discover MoreThe precision of numeric values you display in a worksheet can be less than what is actually maintained by Excel. This ...
Discover MoreExcel allows you to easily combine text together. Interestingly, it provides two ways you can perform such combinations. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments