Identifying Values that Don't Follow a Specific Pattern

Written by Allen Wyatt (last updated April 27, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


4

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.

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://learn.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.

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.

You could also utilize the UDF in a conditional formatting rule to easily highlight cells that don't follow the pattern. I won't go into how to create such a rule here, as I've done it elsewhere in ExcelTips. All you need to do, however, is set up a rule that uses a formula and then use the following as the formula:

=AND(CheckPattern(A1)=FALSE,A1<>"")

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3391) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

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

Ensuring Standard Units During Data Entry

Need to make sure that information entered in a worksheet is always in a given unit of measurement? It's not as easy of a ...

Discover More

Contingent Validation Lists

Data validation can be used to create lists of choices for entry into a particular cell. Using the techniques in this tip ...

Discover More

Deleting Duplicate Text Values

Got a list of data from which you want to delete duplicates? There are a couple of techniques you can use to get rid of ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Adding a Missing Closing Bracket

When working with large amounts of data, it is a good idea to make sure that the data all consistently follows a pattern. ...

Discover More

Changing the Cycling Sequence for the F4 Cell Reference Shortcut

When editing a formula, the F4 shortcut key can be helpful. It may not, however, be helpful in all instances. This tip ...

Discover More

Returning the Rightmost Value in a Row

Do you need to figure out the rightmost value within a row in which not all cells may contain values? This tip provides a ...

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}] (all 7 characters, in the sequence shown) 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 8 + 0?

2024-05-01 12:51:26

Sandeep

Thanks Allen.


2024-04-30 09:35:17

Allen

Sandeep,

I just checked, and there is no redirect on that tip. This is the URL:

https://excelribbon.tips.net/T012654

It goes to a different tip entirely.

-Allen


2024-04-30 09:18:08

sandeep

Dear Woolley, T012654 is redirecting me to T003391_Identifying_Values_that_Dont_Follow_a_Specific_Pattern, which is this tip. Please check & provide correct link.


2024-04-29 10:22:54

J. Woolley

The Tip doesn't mention whether letters in Vishwajeet's part numbers are required to be upper-case. The SEARCH function in the Tip's second formula is not case-sensitive. FIND can be substituted for SEARCH if upper-case letters are required.
The Tip's CheckPattern function will be case-sensitive unless it is in a module headed by the following statement:
    Option Compare Text
My Excel Toolbox includes the following case-sensitive function for convenient use of VBA's Like operator in a cell formula:
    =IsLike(Text, Pattern)
So the Tip's CheckPattern(A1) formula can be replaced by this:
    =IsLike(A1, "##[A-Z][A-Z][A-Z][A-Z][A-Z]####[A-Z]#[A-Z]#")
This formula can be modified to ignore case as follows:
    =IsLike(UPPER(A1), "##[A-Z][A-Z][A-Z][A-Z][A-Z]####[A-Z]#[A-Z]#")
My Excel Toolbox also includes the following case-sensitive function for convenient use of VBScript.RegExp to compare Text with a regular expression Pattern:
    =IsRegEx(Text, Pattern)
So the Tip's CheckPattern(A1) formula can be replaced by this:
    =IsRegEx(A1, "^\d{2}[A-Z]{5}\d{4}([A-Z]\d){2}$")
This formula can be modified to ignore case as follows:
    =IsRegEx(UPPER(A1), "^\d{2}[A-Z]{5}\d{4}([A-Z]\d){2}$")
See https://sites.google.com/view/MyExcelToolbox
See https://excelribbon.tips.net/T012654 for more on this subject.


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.