Written by Allen Wyatt (last updated January 24, 2023)
This tip applies to Excel 2007, 2010, 2013, and 2016
Vishwajeet has a series of part numbers in a column. These part numbers must follow a specifc pattern (2 numbers, 5 letters, 4 numbers, 1 letter, 1 number, 1 letter, and 1 number). He wonders if there is a way to easily identify which of the cells in the column vary from this pattern.
There are a number of ways you can approach this task, depending on the true nature of your data. For instance, you could use a formula like this in a helper column:
=AND(LEN(A1)=15,ISNUMBER(--LEFT(A1,2)),ISTEXT(MID(A1,3,5)), ISNUMBER(--MID(A1,8,4)),ISTEXT(MID(A1,12,1)),ISNUMBER(-- MID(A1,13,1)),ISTEXT(MID(A1,14,1)),ISNUMBER(--RIGHT(A1,1)))
The formula (which is quite long) returns True or False, depending on whether the pattern is correct or not. There is a problem with the formula, however. It won't catch symbols used in place of letters (such as a dollar sign or an asterisk) and it won't catch some symbols used in place of numbers (such as a period or a percent sign). The reason is that the ISTEXT function considers symbols to be text and the ISNUMBER function parses something like "1.23" as a number.
If you want to catch this improper use of symbols, the following formula could be used:
=AND(LEN(A1)=15,ISNUMBER(SUM(SEARCH(MID(A1,{1,2,8,9,10,11, 13,15},1),"0123456789"),SEARCH(MID(A1,{3,4,5,6,7,12,14},1), "ABCDEFGHIJKLMNOPQRSTUVWXYZ"))))
This one works because it uses the SEARCH function to effectively check every character in the part number. One would think that you might need to enter the formula as an array formula (terminating it with Ctrl+Shift+Enter), but interestingly enough, I get no difference in results when I use it as a regular formula vs. an array formula.
If you need to check the part number patterns quite a bit, you may want to consider using a macro to do the checking. The following is a short user-defined function that uses the Like operator to see if the pattern is followed.
Function CheckPattern(rCell As Range) As Boolean Dim sPattern As String sPattern = "##[A-Z][A-Z][A-Z][A-Z][A-Z]####[A-Z]#[A-Z]#" CheckPattern = rCell.Value Like sPattern End Function
Note the use of the sPattern variable. This is the pattern to be followed when the Like operator does its comparison. Each occurrence of the # symbol means that any digit can be in this position. Each occurrence of [A-Z] means that the position can be one letter in the range of A to Z.
You can find more about the meaning of the characters you can include in the pattern by visiting this page at one of Microsoft's sites:
https://docs.microsoft.com/en-us/dotnet/visual-basic/language-reference/operators/like-operator
This site is actually for Visual Basic, not VBA, but this particular page of information will work just fine in VBA.
In order to use the CheckPattern user-defined function, you can place the following in any cell in your worksheet:
=CheckPattern(A1)
This assumes that the part number is in cell A1, as do all the other formulas presented in this tip.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3391) applies to Microsoft Excel 2007, 2010, 2013, and 2016.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Do you ever have a need to return just a few digits out of a number? This tip shows different formulas you can use to ...
Discover MoreIf you have a series of consecutive numbers in a column, you may want to know if it really is consecutive. (In other ...
Discover MoreThe filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-10-17 10:05:57
Dennis Costello
With respect to Nir's observation, ISTEXT(1) returns FALSE, while ISTEXT("1") is TRUE, so he's right that Allen's first formula doesn't work. As to why Allen's second formula need not be entered as an Array formula - I believe the key is the SUM function. The array constants are an effective shorthand way of getting to an intermediate result - he also could have said:
... SUM(SEARCH(MID(A1,1,1), "0123456789"), SEARCH(MID(A1,2,1), "0123456789"), ...
i.e., invoke the SEARCH function once for each character in A1. Any SEARCH that fails returns a #VALUE, and if there are any such errors, the sum is also #VALUE, which is not a number. Instead of ISNUMBER, Allen could have said NOT ISERROR. Clearly, Allen's way, being shorter, still invokes the SEARCH function once for each character but is a lot easier to enter, read, and maintain, and is a Really Neat Trick.
Note that you can also use the SUMPRODUCT function in similar circumstances - any of its array parameters can be an array constant. I often will use this sort of formula when I want to sum several non-adjoining cells from a different workbook:
SUMPRODUCT(<other workbook with a really long path and filename>TAB!$G$5:$G$10, {1;1;0;1;0;1})
because that's shorter than <filename>TAB!G5 + <filename>TAB!G6 + <filename>TAB!G8 + <filename>TAB!G10 . Note I used semicolons to make the array constant a single column - commas would make it a single row.
My only pet peeve with these array constants is that you can't use the % operator with them - i.e., instead of {0%, 25%, 100%, 75%}, you have to enter {0, .25, 1, .75}. I guess that means % is an arithmetic operator instead of a lexical operator. Hmmm...
2017-09-20 12:35:10
Willy Vanhaelen
The need of a helper column can be avoided by using conditional formatting combined with the User Defined Function (UDF) of this tip. You will immediatly see which part numbers have a wrong pattern with the additiional advantage that when entering a new part numbers with a wrong pattern you will notice it at once.
1) copy the UDF of this tip to a module
2) with column A highlighted, click on Conditional Formatting in the Home tab (Styles section)
3) select New Rule...
4) Excel displays the New Formatting Rule dialog box.
5) select "Use a formula to determine which cells to format"
6) the dialog changes (see figure below)
7) type or copy/past the following formula: =AND(CheckPattern(A1)=FALSE,A1<>"")
(see Figure 1 below)
8) Select the formatting of your liking (red background in the image above)
9) click OK
Here is a oneliner version of the UDF:
Function CheckPattern(rCell As Range) As Boolean
CheckPattern = rCell.Value Like "##[A-Z][A-Z][A-Z][A-Z][A-Z]####[A-Z]#[A-Z]#"
End Function
Figure 1.
2017-09-17 00:43:04
Nir Liberman
I`m not sure that the first formula is correct:
cell A1='1A'
formula: =ISTEXT(MID(A1,1,1))
result: TRUE !!!!
and the complete formula:
111aaaa1111a1a1 = TRUE (false true)
11aaaaa1111a1a1 = TRUE (true true)
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 © 2023 Sharon Parq Associates, Inc.
Comments