Written by Allen Wyatt (last updated October 15, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Kim has a column of data used to contain a location code. This code consists of a single letter followed by two digits, such as A03 or B12. Kim would like to conditionally format the column so that anything entered into the column that doesn't use this pattern is highlighted in some way.
There are many ways that this problem can be approached. Each approach depends on developing a formula that can be used within a conditional formatting rule to return either True or False and trigger the conditional format. (This tip won't go into how to create a conditional formatting rule but will instead focus on the various formulas that can be used in the rule. How you create conditional formatting rules is covered in other ExcelTips.)
Whatever formula is put together has to test three things:
Finding out if the text in a cell has only three characters is rather easy; you can use the LEN function to do it:
=LEN(A1)=3
Finding out if the first character is a letter is also rather easy. In fact, there are a couple of ways it can be done. Any of the following will return True if the first character is a letter:
=AND(CODE(LEFT(A1,1))>64,CODE(LEFT(A1,1))<91) =AND(LEFT(A1,1)>="A",LEFT(A1,1)<="Z")
These check to make sure that only an uppercase letter is in the first position. If you want to also accept lowercase letters, then you can use a variation of the second test:
=AND(UPPER(LEFT(A1,1))>="A",UPPER(LEFT(A1,1))<="Z")
If both upper- and lowercase letters are acceptable (along with virtually any other symbol), then you might consider using the following test:
=NOT(ISNUMBER(LEFT(A1,1)+0))
Here are a couple of ways you can apply the third test-whether the second and third characters are digits:
=ISNUMBER(VALUE(RIGHT(A1,2))) =ISNUMBER(--RIGHT(A1,2))
Note that these approaches treat the last two characters together. This means that "1", "11," and "111" would all pass the test—they successfully check out as numbers. If your formula were checking only the last two digits, this could be a problem, but the fact that you will also include the first check (for the overall length of the string in the cell and that it must be 3), then it doesn't present a problem at all.
The trick, now, is to combine your approach-of-choice for each of the three tests into a single formula. This can be done using the AND function. I'll just pick the shortest from each of the tests and combine them in this way:
=AND(LEN(A1)=3, AND(LEFT(A1,1)>="A",LEFT(A1,1)<="Z"),ISNUMBER(--RIGHT(A1,2)))
As written, this formula returns True if all the tests are passed, which means that the cell contains a location code with a valid pattern. This would work great as a conditional format if Kim were to format the column as a color (say, green) and then use the conditional format to remove the green color. This may seem backward, and you may actually only want to apply a format if the pattern isn't met. If that is the case, then simply encase the formula in a NOT function to reverse the True/False that is returned:
=NOT(AND(LEN(A1)=3, AND(LEFT(A1,1)>="A",LEFT(A1,1)<="Z"),ISNUMBER(--RIGHT(A1,2))))
As you can tell, using a formula like this can be a bit tricky. You could, if you prefer, create a UDF (user-defined function) that would make the conditional formatting rule a bit shorter. The following macro is a good way to go:
Function IsBadPattern(sCell As String) As Boolean IsBadPattern = Not(sCell Like "[A-Z][0-9][0-9]") End Function
To use the UDF in your conditional formatting rule, all you need to do is use the following formula:
=IsBadPattern(A1)
The result of the UDF will be TRUE if the string in the referenced cell doesn't match the pattern you wanted. As written, it won't allow for the use of lowercase letters in the first character position. If you need to allow lowercase letters, you don't need to change the UDF. Instead, change the formula to the following:
=IsBadPattern(UPPER(A1))
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9976) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
The conditional formatting capabilities of Excel are very helpful when you want to call attention to different values ...
Discover MoreExcel provides a great conditional formatting capability that allows you to change how a cell appears based on critiera ...
Discover MoreNeed to have your worksheet printout start on a new page every time a value in a column changes? There are a couple of ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-12-26 07:42:44
Simon Freeman
MX&HNY - After consulting my friend Mr Google, and it took him a while, I understand that the "--" in "=ISNUMBER(--RIGHT(A1,2))" is an alternative to the Value function. I have never come across this before. Is it only instead of the Value function, can you use it anywhere, are there other similar alternatives for other functions. How do you find out about it. Thanks - Simon
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 © 2024 Sharon Parq Associates, Inc.
Comments