Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Deleting Everything Up to a Character Sequence.

Deleting Everything Up to a Character Sequence

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


1

Steven has a worksheet that has lots of text in it. In the cells in column A he wants to delete everything that may occur before a given sequence of characters, such as everything before =XX=. There may be multiple instances of these characters in each cell, but Steven only wants to delete everything before the first occurrence.

One way to do this is to use a formula. If you are using Excel 2021 or the version included with Microsoft 365, then you can use the following formula:

=TEXTAFTER(A1,"=XX=")

If you have some cells that may not include your delimiters, then you need to compensate for them. This version of the formula uses the IFERROR function to handle what to do if the delimiter is not there:

=IFERROR(TEXTAFTER(A1,"=XX="),A1)

If you are using an older version of Excel, then you need to rely on a formula that is a bit more complex. For instance, the following formula will evaluate whatever is in cell A1 and simply return everything up to the =XX= characters. If the characters are not found in the cell, then the entire cell is returned:

=RIGHT(A1,IF(ISERROR(FIND("=XX=",A1,1)),
LEN(A1),LEN(A1)-FIND("=XX=",A1,1)+1))

If you want, instead, to not return the first occurrence of =XX=, all you need to do is change the +1 near the end of the formula to -3.

If you prefer a macro-based solution you could use a routine like the following. It examines all the cells that are currently selected and then deletes everything before the =XX= sequence.

Sub DeleteToSequence()
    Dim rCell As Range
    Dim sSeq As String
    Dim x As Long

    sSeq = "=XX="
    For Each rCell In Selection
        x = InStr(rCell.Value, sSeq)
        If x > 0 Then
            rCell.Value = Mid(rCell, x)
        End If
    Next

    Set rCell = Nothing
End Sub

You should be aware that this macro can cause some errors, particularly when what you are searching for begins with an equal sign (as in =XX=). When a string beginning with an equal sign is stuffed back into the cell, you'll get a #NAME? error because Excel tries to parse the cell as if it contains a formula.

If you want to delete everything up through the character sequence, use this If structure in the middle of the routine instead of the one that is in the code above:

If x > 0 Then
    rCell.Value = Mid(rCell, x + Len(sSeq))
End If

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 (8446) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Deleting Everything Up to a Character Sequence.

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

Developing Style Families

Styles, as implemented in Word, represent a powerful way to help you easily standardize your formatting tasks. When ...

Discover More

Changing How Word Presents Your Document

Tired of the old black-on-white text displayed by Word? Depending on your program version, you can configure Word to show ...

Discover More

Saving Money on Printing Labels

Labels can be expensive, and a little common sense will help you waste less money as you try to get your labels to appear ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Stopping the Deletion of Cells

You can delete cells from a worksheet, and Excel will move the remaining cells either to the left or upwards. Deletions, ...

Discover More

Adjusting a Range's Starting Point

Select a range of cells, and one of those cells will always be the starting point for the range. This tip explains how to ...

Discover More

Copying a Cell without Formatting

When you are copying a cell from one place to another (perhaps even to a different worksheet), you may not want to copy ...

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 three minus 2?

2024-03-10 12:09:43

J. Woolley

My Excel Toolbox includes the following function that is useful for manipulating the text described in this Tip:
    =Between(Text, BeginAfter, EndBefore, [CaseSensitive], [Direction])
This function is like a combination of TEXTBEFORE and TEXTAFTER.
The following formulas produce the same results as the Tip's first two formulas but do not require Excel 2021+:
    =Between(A1, "=XX=", "")
    =IFERROR(Between(A1, "=XX=", ""), A1)
See https://sites.google.com/view/MyExcelToolbox/


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.