Highlighting Cells Containing both Letters and Numbers

by Allen Wyatt
(last updated March 2, 2020)

9

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, 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

Applying the All Caps Format

Want your text to always appear in upper-case, regardless of how you type it? Word allows you to add formatting to your ...

Discover More

Changing from Absolute to Relative Hyperlinks

It is easy to amass a large number of hyperlinks in a document. You may want to process these hyperlinks in some way, ...

Discover More

Self-Adjusting Column Widths

It is important to understand how column widths relate to the margins you may have set in your document. The reason is ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Conditionally Formatting Non-Integers

The conditional formatting capabilities of Excel are very helpful when you want to call attention to different values ...

Discover More

Shading Based on Odds and Evens

You can use conditional formatting to add shading to various cells in your worksheet. This tip shows how you can shade ...

Discover More

Returning a Value Based on Text Color

Conditional formatting rules can be used to adjust the way in which information is displayed in Excel, such as the text ...

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 eight more than 6?

2021-08-18 22:28:59

Roy

For a non-macro solution that gives no false positives, one can use the following:

=LEN(TEXTJOIN("",TRUE,IFERROR(VALUE(MID(A1,SEQUENCE(1,LEN(A1)),1)),"")))

Set the first Conditional Formatting rule to test for "=LEN(A1)" (just append that to the end of the above). That tests for all numerals. Set no format so as to not affect the cell. Checkmark "Stop If True" so that it will stop if met.

Set a second CF rule to test for "=0" which tests for all non-numerals (which is the test used above for "all letters" (and certainly valid if only numerals and letters are used. Set no format so as to not affect the cell. Checkmark "Stop If True" so that it will stop if met.

Set a third rule, doesn't matter what so long as it is always true (so... "=A1=A1" is a simple one), or use the above and append "<LEN(A1)" because it must be and so will certainly be true. (It must be because it can't be longer than A1 and it has already been tested to not be the same length. That leaves only "less than.")

Set the desired formatting for this one.

(Checkmark "Stop If True" as a general housekeeping thing in case Excel adds rules after it due to pasting into the range involved, or adds its rules to some other range if something from its range is pasted elsewhere. It can help spot trouble to be investigated while letting such run and maybe have no effect at the moment take a possible hint of brewing trouble away from you.)

The formula separates all the characters into single character strings with MID(), then checks for their VALUE() which non-numerals will error on. IFERROR() then gives the failures a blank result and TEXTJOIN() combines them into a single string, but does not include anything for the blanks (nor any delimiter). One is left with a string that is the same length as the cell's contents if all numerals, is zero-length if all were non-numerals, and will be something between the cell's length and zero if there was a mix. The rules rule out the first two, then apply new formatting for the ones that are mixed.

For a single rule usage, one could just use an NOT(OR()) to wrap the first two conditions mentioned above which would be equivalent to using the first two rules to suss things out, but would be brutally long for the little box it goes in.


2021-05-20 07:02:43

Angeles Martinez Fontal

God bless you Willy! It works :)
Only caveat is I must save the xls as a Macro sheet but I hope the team can live with that. I was saving all macros in the PERSONAL.XLSB file until now

Thank you so so very much!

Love the generosity of spirit found on the Internet when it comes to software tips. I have learnt so much and have thanked so many souls already.

Thank YOU Truly

Angeles


2021-05-19 13:20:04

Willy Vanhaelen

@Angeles
The only simple solution is to use the UDF approach proposed in this tip using the following very small macro that you enter in a module:

Function CheckChars(r As Range) As Boolean
CheckChars = Len(r) And Not r Like "*[0-9]*"
End Function

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

=CheckChars(A1)

Only cells containing no digits will be highlighted. Spaces and punctuation marks are preserved. if you want to exclude those as well, replace "*[0-9]*" with "*[!A-Za-z]*".


2021-05-17 12:18:38

Angeles

Hello Allen,

Thanks for this. It is almost exactly what I need. How can I modify your formula to actually highlight the cells that your formula is not highlighting? I only need to highlight cells containing TEXT, ignoring those with text and numbers

Thanks for any help


2018-07-19 11:07:27

Peter Atherton

Vignesh

If you're text is is A1 and you enter this in B1 =ISNUMBER(MID(A1,4,1)*1) it will return TRUE or FALSE. You can use this in conditional format as in
=ISNUMBER(MID(A1,4,1)*1)=FALSE



(see Figure 1 below)


Figure 1. 




2018-07-18 05:16:04

Vignesh

Hi ,

I have a question, I need to highlight the cell if the fourth digit is "Alphabet". Anyone suggest formulas


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.