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

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)

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,102,695
Messages
5,488,341
Members
407,634
Latest member
ps01

This Week's Hot Topics

  • Timer in VBA - Stop, Start, Pause and Reset
    [CODE=vba][/CODE] Option Explicit Dim CmdStop As Boolean Dim Paused As Boolean Dim Start Dim TimerValue As Date Dim pausedTime As Date Sub...
  • how to updates multiple rows in muliselect listbox
    Hello everyone. I need help with below code. code is only chaning 1st row in mulitiselect list box. i know issue with code...
  • Delete Row from Table
    I am trying to delete a row from a table using VBA using a named range to find what I need to delete. My Range is finding the right cell. In the...
  • Assigning to a variable
    I have a for each block where I want to assign the value in column 5 of the found row to the variable Serv. [CODE=vba] For Each ws In...
  • Way to verify information
    Hi All, I don't know what to call this formula, and therefore can't search. I have a spreadsheet with information I want to reference...
  • Active Cell Address – Inactive Sheet
    How to use VBA to get the cell address of the active cell in an inactive worksheet and then place that cell address in a location on the current...
Top