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.
Written by Allen Wyatt (last updated October 14, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
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:
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.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Excel makes it easy to concatenate (or combine) different values into a single cell. If you need to combine a different ...
Discover MoreThe way you signify that you are entering a formula is to start a cell entry with an equal sign. Here is the reason why ...
Discover MoreWhen you subtract two numbers from each other, you have a certain expectation of what Excel should deliver. What if you ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2016-03-26 05:49:18
Rick Rothstein
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
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments