Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Adding a Missing Closing Bracket

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Adding a Missing Closing Bracket.

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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (123) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Adding a Missing Closing Bracket.

Related Tips:

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

Rick Rothstein    26 Mar 2016, 05:49
Here is another formula that can be used...

=IF(LEFT(A1)="[",SUBSTITUTE(A1&"]","]]","]"),A1)

And using this formula as a base, we can write your macro as a one-liner...

Sub Close_Bracket()
  Selection = Evaluate(Replace("IF(LEFT(@)=""["",SUBSTITUTE(@&""]"",""]]"",""]""),@)", "@", Selection.Address))
End Sub
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.