Highlighting Cells Containing both Letters and Numbers

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


1

Emmanuel would like to know how he can use conditional formatting to highlight a cell if that cell contains a mix of both numbers and letters. If the it contains all letters or all numbers, the cell should not be highlighted.

In this tip I won't focus on how to create a conditional format; there have been plenty of other ExcelTips that focused on that task. What I will focus on is a few formulas you could use in defining the condirtional formatting rule. The formula needs to examine the value in the cell and return "True" if it contains both letters and numbers, and "False" in all other instances.

Here are three different formulas you can try in the rule:

=SUM(IFERROR(FIND(ROW($1:$10)-1,A1),))*ISTEXT(A1)
=AND(ISTEXT(A1),MATCH(FALSE,ISERROR(1*MID(A1,ROW(INDIRECT("1:15")),1)),0))
=AND(SUM(--(ISNUMBER(--MID(A1,ROW(INDIRECT("A1:A"&LEN(A1))),1)))),ISTEXT(A1))

Any of these formulas work just fine (I would personally choose use the shortest one—less typing!), but there is one potential drawback. If you have numeric digits stored in a cell and the cell as formatted as Text, then the formulas will still return "True" and the conditional format is applied. This occurs because each of the formulas use the ISTEXT function, which looks at the format of the cell to see if it contains text.

The easiest way to get around this potential "false positive" is to create a user-defined function (a macro) that can then be referenced in your conditional formatting rule. Here's a very simple UDF that returns "True" only if the cell contents (not its format) contain both letters and numbers:

Function CheckChars(r As Range) As Boolean
    CheckChars = False
    If r Like "*#*" And UCase(r) Like "*[A-Z]*" Then CheckChars = True
End Function

In order to use this in your conditional formatting rule, simply use this formula:

=CheckChars(A1)

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 (13422) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

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

Understanding Smart Cut and Paste

Editing is generally made easier by a feature that Word calls smart cut and paste. If you prefer, you can turn the ...

Discover More

Seeing the Difference on the Status Bar

Do you often need to know the difference between two values in your worksheet? This tip shares a quick little macro that ...

Discover More

Calculating the First Business Day of the Month

Want to know which day of the month is the first business day? The easiest way to determine the date is to use the ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Stopping a Conditional Formatting Rule from Breaking into Smaller Ranges

When you paste information into a row that is conditionally formatted, you may end up messing up the rules applied to ...

Discover More

Remove Conditional Formatting but Retain the Effects

If you want to get rid of conditional formatting rules, but retain any formatting that was applied by those rules, then ...

Discover More

Conditionally Formatting Cells Containing Dates

Need to know if a particular cell contains a date value? Excel doesn't have a worksheet function to determine this ...

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 2 + 4?

2022-11-19 15:43:18

J. Woolley

The Tip's three formulas and one function (UDF) do not distinguish between ordinary text vs letters and numbers (numerals); for example, text like #1x$2y&3z returns TRUE.
This new version of CheckChars returns TRUE only when the text has both letters and numerals and nothing else:

Function CheckChars(r As Range) As Boolean
s = UCase(r)
CheckChars = s Like "*#*" And s Like "*[A-Z]*" _
And Not s Like "*[!0-9A-Z]*"
End Function

My Excel Toolbox includes the following general function:

Function IsLike(Text As String, Pattern As String) As Boolean
IsLike = Text Like Pattern
End Function

Therefore, this formula matches the new version of CheckChars for cell A1:
=LET(s,UPPER(A1),AND(IsLike(s,"*#*"),IsLike(s,"*[A-Z]*"),NOT(IsLike(s,"*[!0-9A-Z]*"))))
See https://sites.google.com/view/MyExcelToolbox
Curiously, a conditional formatting formula rule cannot reference a UDF that is in an add-in; such a reference must be in the same workbook. But there is a work-around using defined names. See the Conditional Formatting section at https://sites.google.com/view/MyExcelToolbox/caution


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.