+ Reply to Thread
Results 1 to 10 of 10

Create multiple ranges based on an index of values that are also used as range names

Hybrid View

  1. #1
    Registered User
    Join Date
    12-19-2012
    Location
    Bora Bora
    MS-Off Ver
    Excel 2007
    Posts
    5

    Thumbs up Create multiple ranges based on an index of values that are also used as range names

    Hello,

    I am pretty new to VBA (my third mini-VBA code project ever...pretty excited, actually and this is by far the most complex thing I tried to tackle) I am running into issue with execution of my code and I would like to solicit some suggestions.

    Objective: to create multiple named ranges based on index data point pertinent to that specific data set. Then set that index data point as the name of that specific range.

    I manually hardcoded an index in column A which contains mostly blank cells and a few data points which I would like to use as names for a range of values to the right of the index. Here is the approach I have taken:

    1. loop over the index
    2. keep looping if blank
    3. end the loop if come to a value "end"
    4. if the cell is neither of those then take cell value and use it as a name for a range that should span 7 columns to the left and 40 rows down

    Here is the code I have so far, it doesnt execute and I am just too "green" to pick out the issue. Went at it for a few hours now trying a few different things, but no success. Could some one please offer some tips or suggestions?

    I am also attaching a sample workbook I am working on...I need this because eventually I will have 30-40 data tables (which might vary in length of rows, but I'll figure that one out later) which I will need to create named ranges for.

    Thank you for your time and insights

    Code:

     
        Sub RAINgMaker()
    
        Dim index, lastrow As Range
        Dim cellvalue As String
     
     Set index = Sheets("DEALER").Range("A1:A999")
        lastrow = ActiveSheet.Cells(Rows.Count, "A").End(xlUp).Row
        With index
            For i = 1 To lastrow
                If Selection.Cells.Value = 0 Then
                ' do nothing and go to the next loop
                ElseIf cell.Value = "End" Then
                Exit For 'end this loop and move to the next whole loop that look at the next tab, ending procedure for this loop
                Else
                    For Each cellvalue In index
                         Selection.Cells.Value = cellvalue
                    'get the value of the index cell
                    Range(ActiveCell, ActiveCell.Offset(7, 40)).Name = cellvalue
                    'create a range that is to the side of the cell, 7 cells to the right and 40 cells down ...and name it with "cellvalue"
    
            End If
           Next
        End With
    
    
    End Sub

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Create multiple ranges based on an index of values that are also used as range names

    How about this:
    Sub CreateNames()
    Dim rngA As Range, myStr As String, a As Long
    
    With ActiveSheet
        Set rngA = .Range("A:A").SpecialCells(xlConstants)
        
        For a = 1 To rngA.Areas.Count
            myStr = "'" & .Name & "'!R" & rngA.Areas(a).Cells(1).Row & "C1"
            ActiveWorkbook.Names.Add Name:=rngA.Areas(a).Cells(1).Value, RefersToR1C1:="=OFFSET(" & myStr & ", , ,7, 40)"
        Next a
    End With
    
    End Sub
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  3. #3
    Registered User
    Join Date
    12-19-2012
    Location
    Bora Bora
    MS-Off Ver
    Excel 2007
    Posts
    5

    Re: Create multiple ranges based on an index of values that are also used as range names

    Thank you for the help. This works great!

    Is there a way to make the range select more dynamic? I will have ranges that will span more than 7 cells down and vary in length. Can the formula identify those outliers and create a custom range length for each?

    Thank you for your help. This is a huge time saver!

  4. #4
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Create multiple ranges based on an index of values that are also used as range names

    Can the formula identify those outliers and create a custom range length for each?
    Anything you can create a logic method to do it manually can be automated. Once you figure out what the consistent steps are to determine the dynamic range for each area, post it up with a sample workbook.

    Click GO ADVANCED and use the paperclip icon to post up a copy of your workbook.

  5. #5
    Registered User
    Join Date
    12-19-2012
    Location
    Bora Bora
    MS-Off Ver
    Excel 2007
    Posts
    5

    Thumbs up Re: Create multiple ranges based on an index of values that are also used as range names

    Example.xlsmExample.xlsm

    Hello, here is an example workbook with the data.

    I manually created an index to assign names to each data set. Now I need to figure out how to keep the range selection dynamic, so when I get a different length data set, the code only encompases that range in the creation process.

    I wanted to initially build a loop to test each value within the data set and return the first blank cell and use that as a reference, but I feel like there is a more efficient way to achieve my purpose.

    Thank you for your help so far, any suggestions are highly appreciated.

  6. #6
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Create multiple ranges based on an index of values that are also used as range names

    If you design each area with no blank rows within the datablock, this becomes very easy to do. You willing to make that change? Just leave blank rows between sections...

  7. #7
    Registered User
    Join Date
    12-19-2012
    Location
    Bora Bora
    MS-Off Ver
    Excel 2007
    Posts
    5

    Re: Create multiple ranges based on an index of values that are also used as range names

    Hey,

    Having no rows within the data would work. I can manually delete them or come up with some code for it later (such as if only one row is blank that delete it, if more than one leave it the same).

    Here is the example.xls file without the rows in between for the reference.

    Thank you very much for your time.Example.xlsx

  8. #8
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Create multiple ranges based on an index of values that are also used as range names

    Still pretty easy this way:
    Sub CreateNames()
    Dim rngA As Range, a As Long
    
    With ActiveSheet
        Set rngA = .Range("A:A").SpecialCells(xlConstants)
        
        For a = 1 To rngA.Areas.Count
            ActiveWorkbook.Names.Add Name:=rngA.Areas(a).Cells(1).Value, _
                RefersTo:=rngA.Areas(a).CurrentRegion
        Next a
    End With
    
    End Sub

  9. #9
    Registered User
    Join Date
    12-19-2012
    Location
    Bora Bora
    MS-Off Ver
    Excel 2007
    Posts
    5

    Re: Create multiple ranges based on an index of values that are also used as range names

    .CurrentRegion works great. Thank you for all the help!

  10. #10
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Create multiple ranges based on an index of values that are also used as range names

    I have marked this thread solved for you.
    In the future please select Thread Tools from the menu above and mark the thread as solved. Thanks.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1