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: Deleting All Names but a Few.

Deleting All Names but a Few

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


2

Do you routinely work with worksheets that contain dozens (or hundreds) of named cells, and most of those names are unnecessary? Cleaning up the names can be a huge task, but getting rid of the ones you don't need can make your workbook smaller and more efficient. The problem is, how do you get rid of a lot of unnecessary names all at once? You can certainly delete them one at a time, but such a process quickly gets tiresome. You could also use the Name Manager to delete them (press Ctrl+F3), but that can be very time consuming as well.

One possible solution is to simply create a new workbook and copy the cells from the old workbook to the new one. Highlight the cells in the old workbook, use Ctrl+C to copy them, then paste them into worksheets in the new workbook. This will copy almost everything from the old workbook—formulas, formatting, etc. It does not copy over print settings or range names. The only task then remaining is to redefine the few names you want in the new workbook.

If you prefer to work with the old workbook (the one with all the names), it is best to create a macro that will do the name deletion for you. You need a macro that will allow you to delete all the names except those you want to keep. The following is a simple approach that accomplishes this task:

Sub DeleteSomeNames()
    Dim vKeep
    Dim nm As Name
    Dim x As Integer
    Dim AWF As WorksheetFunction

    'Add Names to keep here
    vKeep = Array("Name1", "Name2")

    Set AWF = Application.WorksheetFunction
    For Each nm In ActiveWorkbook.Names
        x = 0
        On Error Resume Next
        x = AWF.Match(nm.Name, vKeep, 0)
        On Error GoTo 0
        If x = 0 Then
            nm.Delete
        End If
    Next
    Set AWF = Nothing
End Sub

Before using the macro, modify the line that creates the vKeep array. Simply enter the names you want to keep within the array, each name surrounded by quotes and separated by commas. (In the example shown here, the names "Name1" and "Name2" will be kept.) The macro loops through all the names in the workbook and uses the Match function to see if the name is one in the array. If it is not, then it is deleted.

If you prefer to use a third-party solution to managing the names in your workbook, a great choice is the Name Manager add-in, written by Jan Karel Pieterse. You can find more information on the add-in here:

https://jkp-ads.com/excel-name-manager.asp

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 (11787) 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: Deleting All Names but a Few.

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

Getting Rid of Fields Inserted by Third-Party Programs

Third-party programs can be used to affect a document and change what is contained therein. Of course, getting rid of ...

Discover More

Inserting Rows

Need to insert rows in your worksheet? Excel provides a few techniques you can use to do this. Here are some ideas you ...

Discover More

Determining the Used Range

You may have a need to determine the range occupied by data within a worksheet. The approach you take in devising a ...

Discover More

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!

More ExcelTips (ribbon)

Can't Enter Years in a Cell

Sometimes getting the right thing to show up in a cell can be a bit tricky when working with dates. If you enter a year ...

Discover More

Clearing and Deleting Cells

When you want to remove information from a worksheet, you can either clear cells or delete cells. This tip examines the ...

Discover More

Displaying Row and Column Labels

When you create a worksheet, it is common to place headings at the top of each column and the left of each row so you can ...

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 five minus 1?

2023-03-04 12:10:33

J. Woolley

For related discussion, see https://excelribbon.tips.net/T010338_Getting_Rid_of_Unused_Range_Names.html


2022-12-17 09:38:52

J. Woolley

My Excel Toolbox includes the following dynamic array function to list defined names (named ranges) with workbook, worksheet, or any scope, including names that are normally hidden:
=ListNames([Scope],[SkipHidden],[SkipHeader])
The list includes the following columns: Scope, Name, Visible, Refers To, Value, Comment.
See https://sites.google.com/view/MyExcelToolbox/
In older versions of Excel you can use it with the SpillArray function like this:
=SpillArray(ListNames(...))
See UseSpillArray.pdf at https://drive.google.com/file/d/1HTw_rYNZR2I6dE9C__qFhbd8YtC7rv17/view


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.