VBA to create multiple named ranges

SPY

New Member
Joined
Nov 9, 2006
Messages
29
Hi
I need to create multiple named ranges to use in chart series.

Column C contains the name to be used for the named range and Columns D:S contain the data. Some of the rows don't have a complete range of data in D:S so would need to check for blanks.

Any help appreciated!
 

Some videos you may like

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.

tonyyy

Well-known Member
Joined
Jun 24, 2015
Messages
1,647
You might consider the following as a start...

Code:
Sub CreateNamedRanges()

Dim LastRow As Long
Dim r As Range

LastRow = Cells(Rows.Count, "C").End(xlUp).Row

For Each r In Range("C1:C" & LastRow)
    Range(r.Offset(0, 1), r.Offset(0, 17)).Name = r.Value
Next r

End Sub
It doesn't address "blanks" - as you didn't specify if the blanks are all at the end of the row or if they could be interspersed within the row. And in the case of the latter, would you want to move the cells to the left to eliminate the blanks? Or something else?

Cheers,

tonyyy
 

SPY

New Member
Joined
Nov 9, 2006
Messages
29
Thanks Tonyyy that's brilliant!

With regards to the problem with blanks, these would be at the end of some rows and as a result the range will be shorter eg D:P when QR&S are blank
 

tonyyy

Well-known Member
Joined
Jun 24, 2015
Messages
1,647
Now adjusted for blank cells at the end of the row...

Code:
Sub CreateNamedRanges()
Application.ScreenUpdating = False

Dim LastRow As Long
Dim LastCol As Long
Dim r As Range

LastRow = Cells(Rows.Count, "C").End(xlUp).Row

For Each r In Range("C1:C" & LastRow)
    LastCol = Cells(r.Row, Columns.Count).End(xlToLeft).Column
    Range(r.Offset(0, 1), r.Offset(0, LastCol - 3)).Name = r.Value
Next r

Application.ScreenUpdating = True
End Sub
Cheers,

tonyyy
 

Watch MrExcel Video

Forum statistics

Threads
1,099,684
Messages
5,470,114
Members
406,681
Latest member
sachinmasurkar

This Week's Hot Topics

Top