Highlighting Cells Containing both Letters and Numbers

by Allen Wyatt
(last updated March 2, 2020)

8

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

Using a Formula in a Footer

Excel won't let you place a formula directly into a footer. You can, however, create a simple macro that will produce the ...

Discover More

Preventing a Frame when Converting a Table to Text

Tables, in Word, can either be inline with the rest of your text or the text can wrap around the table. If you have ...

Discover More

Rounding to the Nearest $50

When preparing financial reports, it may make your data easier to understand if you round it to the nearest multiple, ...

Discover More

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!

More ExcelTips (ribbon)

Conditional Formatting for Errant Phone Numbers

Conditional formatting can be used to draw attention to all sorts of data based upon the criteria you specify. Here's how ...

Discover More

Highlighting Values that are 10x a Baseline Value

Sometimes the hardest part of getting your conditional formatting rules to work properly is figuring out the proper way ...

Discover More

Conditional Format that Checks for Data Type

Conditional formatting can be used to highlight cells that contain the improper type of data for your needs. This tip ...

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 four more than 3?

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.