Named Ranges – VBA properties & actions

Named Ranges are a very useful feature of Excel, but a lot of users do not know why or how to use them.  This post is not about how to use Named Ranges, but specifically how to create, delete and manage Named Ranges automatically with VBA.

Create Named Ranges

Named Ranges can be created at the Worksheet or the Workbook level.

'Create Named Range - at the workbook level Method 1
 ThisWorkbook.Worksheets("Sheet1").Range("$A$1:$B$5").Name = "Range1"

 'Create Named Range - at the workbook level Method 2
 ThisWorkbook.Names.Add Name:="Range1", RefersTo:="=Sheet1!$C$1:$D$5"

 'Create Named Range - at the worksheet level Method 1
 ThisWorkbook.Worksheets("Sheet1").Names.Add Name:="Range1", RefersTo:="=Sheet1!$C$1:$D$5"

Delete Named Ranges

'Delete Named Range
 Names("Range1").Delete

Change visibility of Named Ranges

'Hide Named Ranges from the Name Manager
Names("Range1").Visible = False


 'Make the Named Range visible in the Name Manager
 Names("Range1").Visible = True

Looping through each Named Range

'Loop through each Named Range
 Dim NamedRange As Name
 For Each NamedRange In ActiveWorkbook.Names
     MsgBox NamedRange.Name & " : " & NamedRange.RefersTo
 Next

Create Named Ranges automatically from ranges

It is possible to automatically create a named range based on the cells to the left, top, right or bottom of another cell.  In this example below cells A1 – C1 will become the names for the Ranges A2-A10, B2-B10 and C2-C10.

'Create Named Ranges automatically from ranges
ActiveSheet.Range("A1:C10").CreateNames Top:=True

'Create Named Ranges automatically from the selection
Selection.CreateNames Top:=True

Depending on the location of the names we can use the following settings:

Left:=True
Top:=True
Bottom:=True
Right:=True

The “Print_Area”

If we set a print area using the standard Excel Ribbon: Page Layout -> Print Area -> Set Print Area this will automatically create a named range called “Print_Area”.  This is a reserved name which is purely for the print area.  Therefore, we can control the Print_Area like any other named range, we just have to use the correct name.  But we need to be aware that the Print_Area is a worksheet level item, as each worksheet can have it’s own print area.

'Create a Print_Area - Method 1
ThisWorkbook.Worksheets("Sheet1").Names.Add Name:="Print_Area", RefersTo:="=Sheet1!$C$1:$D$5"

'Create a Print_Area - Method 2
ActiveSheet.PageSetup.PrintArea = "$C$1:$D$5"

'Clear the Print_Area
ActiveSheet.PageSetup.PrintArea = ""

Discover how you can automate your work with our Excel courses and tools.

Excel Academy

Excel Academy
The complete program for saving time by automating Excel.

Excel Automation Secrets

Excel Automation Secrets
Discover the 7-step framework for automating Excel.

Office Scripts Course

Office Scripts: Automate Excel Everywhere
Start using Office Scripts and Power Automate to automate Excel in new ways.

Leave a Comment