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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13422) applies to Microsoft Excel 2007, 2010, 2013, and 2016.
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!
Want to know where duplicates are in a list of names? There are a couple of ways you can go about identifying the ...
Discover MoreWhen preparing a report for others to use, it is not unusual to add a horizontal line between major sections of the ...
Discover MoreIf you need to shade alternating rows in a data table, you'll want to examine how you can accomplish the task with ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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.
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 © 2021 Sharon Parq Associates, Inc.
Comments