Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Extracting a Pattern from within Text.

Extracting a Pattern from within Text

by Allen Wyatt
(last updated February 18, 2017)

3

Tom has a worksheet that contains about 20,000 cells full of textual data. From within these cells he needs to extract a specific pattern of text. The pattern is ##-##### where each # is a digit. This pattern does not appear at a set place in each cell. Tom wonders if there is a way to extract the desired information.

There are several ways that you can approach this problem, and the correct solution for your needs will depend on the characteristics of the data with which you are working. If you know that the only place in your data that you will have a dash is within your pattern, then you can key off of the presence of the dash by using a formula such as the following:

=MID(A1,FIND("-",A1)-2,8)

This finds the dash and then grabs the two characters to the left of the dash. This obviously will not work if there are dashes in other places in the text or if it is possible to have "patterns" that include non-digits (such as 12-34B32) and you want those excluded. In that case you'll need a much more complex formula:

=IF(ISERROR(INT(MID(A1, FIND("-", A1, 1)-2, 2)) & INT(MID(
A1, FIND("-", A1, 1)+1, 5))), "", MID(A1, FIND("-", A1)-2, 8))

This includes an error-checking component that finds out if the characters just before the dash and just after the dash contain anything other than digits. If they do, then nothing is returned.

The one thing that these formulaic approaches don't do is to handle those situations where there may be more than one occurrence of the pattern within the same cell. In that case, a macro is the best approach. The following will extract the valid patterns and place them in a new worksheet called "Results."

Sub ExtractPattern()
    On Error Resume Next
    Set SourceSheet = ActiveSheet
    Set TargetSheet = ActiveWorkbook.Sheets("Results")
    If Err = 0 Then
        Worksheets("Results").Delete
    End If
    Worksheets.Add
    ActiveSheet.Name = "Results"
    Set TargetSheet = ActiveSheet
    Cells(1, 1).Value = "Found Codes"
    Cells(1, 1).Font.Bold = True
    iTargetRow = 2

    SourceSheet.Select
    Selection.SpecialCells(xlCellTypeLastCell).Select
    Range(Selection, Cells(1)).Select

    For Each c In Selection.Cells
        If c.Value Like "*##-#####*" Then
            sRaw = c.Value
            iPos = InStr(sRaw, "-")
            Do While iPos > 0
                If iPos < 3 Then
                    sRaw = "  " & sRaw
                    iPos = iPos + 2
                End If
                sTemp = Mid(sRaw, iPos - 2, 8)
                sRaw = Mid(sRaw, iPos + 6, Len(sRaw))
                If sTemp Like "##-#####" Then
                    TargetSheet.Cells(iTargetRow, 1) = sTemp
                    iTargetRow = iTargetRow + 1
                Else
                    sRaw = Mid(sTemp, 4, 5) & sRaw
                End If
                iPos = InStr(sRaw, "-")
            Loop
        End If
    Next c
End Sub

Note that the macro uses the Like function in two places. The first instance determines if the pattern occurs anywhere in the cell, and the second instance is used to determine if the extracted characters exactly match the desired pattern.

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 (12332) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Extracting a Pattern from within Text.

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

Button for Leaving Full-Screen Mode

If you display your document in full-screen mode, there are a couple of ways you can get back to normal mode. One method ...

Discover More

Changing the Reference in a Named Range

Define a named range today and you may want to change the definition at some future point. It's rather easy to do, as ...

Discover More

Standardizing Note Reference Placement

Want to modify where an endnote or footnote reference appears in relation to the punctuation in a sentence? Here's a way ...

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)

Indirectly Referencing a Cell on a Different Worksheet

Excel includes the powerful INDIRECT function which can be used to assemble references to other cells in your workbook. ...

Discover More

Pulling Initial Letters from a String

When working with names or a different series of words, you may need to pull the initial letters from each word in the ...

Discover More

Checking for Either of Two Text Values

Using a formula to find information in a text value is easy. Using a formula to find either of two text values within 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}] 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 five more than 4?

2017-02-20 08:33:30

Madhav

Thanks Peter for your interest and some tips.

My patterns are fixed
##-##-# or ###-##-# or ####-##-or #####-##-# or ######-##-# or #######-##-#
there will be space before them and then space or comma after them..

The source data could be "1-ab-4-abjljghkfdhjgf-2 nfkkgfg 2-nsnfkd 12345-67-8 mn,nfdgfd 2345-45-8, 2346799-91-0 nfkgjfdgfdj" I would like to extract only 12345-67-8 2345-45-8 2346799-91-0 so the patterns that I want to extract are #######-##-# ######-##-# #####-##-# ####-##-# ###-##-# ##-##-# wherein # is a digit... .. only variable length is of the starting digit string which could be 2 to 7 in length.. I just want ignore numbers and hyphens associated with text.. extract numbers with 2 to 7 digits-2 digits - 1 digit. Can you please help?


2017-02-19 10:37:07

Peter Atherton

Madhav

If you just need to extract all the numbers then the substitute function will do this.


Code Numbers Formulas
45-56-7 45567 =SUBSTITUTE(A2, "-", "")
123-112-7 1231127 =SUBSTITUTE(A3, "-", "")
56-*456-*147 56456147 =SUBSTITUTE(A4, "-*", "")

To extract part of the number, say 456 from the last code you need something else.


2017-02-18 04:57:59

Madhav

I would like to extract a pattern like ##-##-# or ###-##-# or ####-##-or #####-##-# or ######-##-# or #######-##-# where # is integer (0 to 9). This pattern may be present in text containing alphanumeric strings. There may be a space or , between the above patterns and the next string. Another strings present could be 1-*-5-*-any text. I would just like to ignore anything else but the digital pretends above. Can you please help?


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.