Highlighting Cells Containing both Letters and Numbers

by Allen Wyatt
(last updated January 16, 2016)

3

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)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13422) applies to Microsoft Excel 2007, 2010, 2013, and 2016.

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

Working with Colors in a Macro

The colors used in a Excel are not as simple as they used to be. Here are some ideas relative to working with those colors in ...

Discover More

Displaying a Hidden First Column

Hiding columns is easy, even hiding column A. How, then, do you get that left-most column displayed again? Here are a few ...

Discover More

Typing Pronunciations of Words

Take a look in a dictionary at the way that words are phonetically spelled. Those special characters used to type those ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Conditionally Highlighting Cells Containing Formulas

Excel's conditional formatting feature allows you to create formats that are based on a wide variety of criteria. If you want ...

Discover More

Protecting Your Conditional Formatting Rules

If you have conditional formatting applied in a worksheet, the formulas in those formats may not be as secure as you would ...

Discover More

Changing Font Face and Size Conditionally

Conditional formatting does not allow you to change the typeface and font size used in a cell. You can write your own macro ...

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}] 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 7 - 0?

2016-01-18 13:35:52

Michael (Micky) Avidan

Sorry,
Missed the formulas at the upper part of the tip.
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2016-01-18 13:33:39

Michael (Micky) Avidan

@To whom it may concern:
For the range B2:B8 > FIRST YOU MUST SELECT that range and then declare the C.F. relying on a formula such as:

=SUM(IFERROR(FIND(ROW($1:$10)-1,B2),))*ISTEXT(B2)

See sample in the following links:
http://jpg.co.il/view/5690ef1a0823f.png/
http://screenpresso.com/=66Tgg
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2016-01-18 00:25:11

Niranjan

Thanks for this tip. It's going to be useful for many for sure.


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.