Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. 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: Adding a Missing Closing Bracket.

Adding a Missing Closing Bracket

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


Terry has a huge list of names in an Excel worksheet. Some are just the names, but some have words in brackets after them. Unfortunately, some of the words in brackets don't have the closing bracket and Terry has to manually add the closing bracket. He wonders if there is a way that he can add a bracket using a wild card search and replace.

The short answer is that you can't do this using a search and replace, either wild card or regular. You can, however, use a formula to add any missing brackets. The following is just one example of the type of formula you can use:

=IF(AND(NOT(ISERROR(SEARCH("[",A1))),NOT(RIGHT(A1,1)="]")),A1&"]",A1)

The trick is to check to see if the cell (A1 in this case) has a left bracket in it and, if it does, check for the right bracket. If the right bracket isn't found, then you append one to the contents of the cell. Here's another variation on the same formulaic theme:

=IF(ISERROR(FIND("[",A1)),A1,IF(ISERROR(FIND("]",A1)),A1&"]",A1))

If you have to check large numbers of cells for missing brackets on a regular basis, you may want to create a macro that will examine a range of cells and add a right bracket if one is needed. Here's an example of how such a macro could be formulated:

Sub Close_Bracket()
    Dim c As Range
    Const csLBrk As String = "["
    Const csRBrk As String = "]"

    On Error Resume Next
    For Each c In Selection.Cells
        If InStr(1, c.Value, csLBrk) > 0 And _
          InStr(1, c.Value, csRBrk) = 0 Then
            c.Value = c.Value & csRBrk
        End If
    Next c
End Sub

To use the macro, simply select the range of cells you want to affect, and then run it. The cells are examined in-place and modified, if needed.

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 (126) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Adding a Missing Closing Bracket.

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

Shortcut Key for Format Painter

The Format Painter is great for copying formatting from one cell to another. If you don't want to grab the mouse to use ...

Discover More

Changing How Footnote References Appear

Footnote references normally appear as superscripted digits, both in the main body of your document and in the footnotes ...

Discover More

Cannot Set Heading Rows in a Table

Word allows you to specify which rows in a table should be considered headings. What if setting the headings doesn't work ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Last Non-Zero Value in a Row

If you have a lot of values in a single row, you might want to pull the last non-zero value from that row. There are a ...

Discover More

Separating Names into Individual Columns

If you have a list of names in a column, and you want to separate those names into individual cells, there are several ...

Discover More

Determining Winners, by Category

Do you need to determine the top three values in a range of columns? The techniques discussed in this tip will come in ...

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 seven more than 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.