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

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.

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
 

Subscribe on YouTube

Watch MrExcel Video

Forum statistics

Threads
1,106,185
Messages
5,509,668
Members
408,748
Latest member
tevian

This Week's Hot Topics

  • Turn fraction around
    Hello I need to turn a fraction around, for example I have 1/3 but I need to present as 3/1
  • TIme Clock record reformatting to ???
    Hello All, I'd like some help formatting this (Tbl-A)(Loaded via Power Query) [ATTACH type="full" width="511px" alt="PQdata.png"]22252[/ATTACH]...
  • TextBox Match
    hi, I am having a few issues with my code below, what I need it to do is when they enter a value in textbox8 (QTY) either 1,2 or 3 the 3 textboxes...
  • Using Large function based on Multiple Criteria
    Hello, I can't seem to get a Large formula to work based on two criteria's. I can easily get a oldest value based one value, but I'm struggling...
  • Can you check my code please
    Hi, Im going round in circles with a Compil Error End With Without With Here is the code [CODE=rich] Private Sub...
  • Combining 2 pivot tables into 1 chart
    Hello everyone, My question sounds simple but I do not know the answer. I have 2 pivot tables and 2 charts that go with this. However I want to...
Top