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

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.

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,101,935
Messages
5,483,779
Members
407,410
Latest member
catherinejoy

This Week's Hot Topics

  • Finding issue in If elseif else with For each Loop
    Finding issue in If elseif else with For each Loop I have tried this below code but i'm getting in Y column filled with W005. Colud you please...
  • MsgBox Error
    Hi Guys, I have the below error show up when i try and run my macro in File1 but works fine if i copy and paste the same code into file2. [ATTACH...
  • CELL FORMAT - IF CONDITION
    My Cell Format is [B]""0.00" Cr". [/B]But in the cell, it is showing 123.00 for editing. (123 is entry figure). (Data imported from other...
  • Show numbers nearly the same
    Is this possible. I have a number that can change very time eg 0.00001234 Then I have a lot of numbers 0.0000001, 0.0000002, 0.00000004...
  • Please i need your help to create formula
    I need a formula in cell B8 to do this >>if b1=1 then multiply ( cell b8) by 10% ,if b1=2 multiply by 20%,if=3 multiply by 30%. Thank you in...
  • Got error while adding column and filter
    Got error while adding column and filter In column Z has some like "Success" and "Error". I want to add column in AA if the Z cell value is...
Top