Relative Column Absolute Row Code

SewStage

Board Regular
Joined
Mar 16, 2021
Messages
70
Office Version
  1. 365
Platform
  1. Windows
Hopefully a quick and easy solution: I have the following code that automatically creates defined names within a certain tab. It works great, but Name Manager continues to show it as $D$56 for instance and I need it to be D$56. I've searched Mr Excel and and the internet but am not a VBA expert at all, so I'm not sure of the correct syntax or where to put it within this code...?

VBA Code:
Public Sub subCreateNamedRanges()
' https://www.mrexcel.com/board/threads/autofill-naming-defined-names.1234019/
Dim Ws As Worksheet
Dim strMsg As String
Dim rngRangeList As Range
Dim Rng As Range
Dim s As String
Dim NamedRange As Name
Dim strName As String
Dim blnSheet As Boolean
Dim rngAddress  As Range
Dim intRow As Integer
Dim strColumns As String
Dim strCodes As String
Dim i As Integer
Dim arrColumns() As String
Dim arrCodes() As String
Dim WsList As Worksheet
Dim intCount As Integer

    ActiveWorkbook.Save
    
    strMsg = "Do you want to set the named ranges for the '" & ActiveSheet.Name & "' worksheet?"
    
    If MsgBox(strMsg, vbYesNo, "Security Question") = vbNo Then
        MsgBox "Activate the correct sheet before you run this code.", vbOKOnly, "Information"
        Exit Sub
    End If
    
    Set Ws = ActiveSheet
    
    On Error Resume Next
    Application.DisplayAlerts = False
    Worksheets("NamedRangeList1234019").Delete
    Application.DisplayAlerts = True
    On Error GoTo 0
    Worksheets.Add after:=Sheets(Sheets.Count)
    ActiveSheet.Name = "NamedRangeList1234019"
    Set WsList = ActiveSheet
        
    WsList.Range("A2:F20000").Cells.ClearContents
    
    Ws.Activate
        
    strColumns = "D"
    arrColumns = Split(strColumns, ",")
    
    strCodes = Replace("PCBMO", " ", "", 1)
        
    arrCodes = Split(strCodes, ",")
    
    For i = LBound(arrColumns) To UBound(arrColumns)
                    
        For intRow = 1 To 25
        
            strName = arrCodes(i) & intRow
                    
            Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)
                        
            With WsList
                .Range("A" & Rows.Count).End(xlUp)(2) = strName
                .Range("B" & Rows.Count).End(xlUp)(2) = "'" & Ws.Name & "!" & rngAddress.Address
            End With
            
            ThisWorkbook.Names.Add Name:=strName, RefersTo:=rngAddress
            
            intCount = intCount + 1
            
        Next intRow
        
    Next i
    
    ActiveWorkbook.Save
    
    WsList.Activate
    
    With WsList.Range("A1").CurrentRegion
    
        .Font.Size = 16
        .Font.Name = "Arial"
        .EntireColumn.AutoFit
        .VerticalAlignment = xlCenter
        With .Rows(1)
            .Value = Array("Name", "Address")
            .Font.Bold = True
            .Interior.Color = RGB(219, 219, 219)
        End With
        .RowHeight = 28
        With .Borders
            .LineStyle = xlContinuous
            .Weight = xlThin
            .ColorIndex = vbBlack
        End With
        .IndentLevel = 1
        
    End With
    
    WsList.Range("A2").Select
    ActiveWindow.FreezePanes = True
    
    strMsg = intCount & " named ranges have been created."
    strMsg = strMsg & vbCrLf & "These have been listed in the " & WsList.Name & " worksheet."
    
    MsgBox strMsg, vbInformation, "Confirmation"
            
End Sub
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
I believe that is what the Name Manager always does. If you manually create a named range, it does the same thing.
However, if you have a named range that is defined to be $A$1:$C$3 and try to insert a row at row 2, the named range will automatically grow to: $A$1:$C$4

So, I guess the question is why do you think you need it to be $C56 instead of $C$56?
If we fully understand what you are trying to do and why, we may be able to provide alternatives.
 
Upvote 0
Here is an approach you can experiment with:
VBA Code:
Dim RefStr As String
RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
ThisWorkbook.Names.Add Name:=strName, RefersTo:=RefStr
 
Upvote 0
I believe that is what the Name Manager always does. If you manually create a named range, it does the same thing.
However, if you have a named range that is defined to be $A$1:$C$3 and try to insert a row at row 2, the named range will automatically grow to: $A$1:$C$4

So, I guess the question is why do you think you need it to be $C56 instead of $C$56?
If we fully understand what you are trying to do and why, we may be able to provide alternatives.
Thanks Joe4. To be clear, I need C$56 not $C56. I have a convoluted spreadsheet; bottom line is that I don't want to manually define names to all Jan-Dec columns and 25 rows, which would be 300 manual entries the next time I need to make a change to this range. I know from past defined names that if I enter C$56 it will carry across all 12 columns. This tab tracks the quantities of all the finished products I have; a different tab tracks the quantities of raw materials needed for each product; finally a third tab calculates current/monthly raw materials inventory based on a calculation of the first two tabs. Hopefully that provides more clarity.
 
Upvote 0
Here is an approach you can experiment with:
VBA Code:
Dim RefStr As String
RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
ThisWorkbook.Names.Add Name:=strName, RefersTo:=RefStr
Thank you. I know enough to know where to put the Dim RefStr As String line, but not sure the best place to insert the last two lines. I added them in the positions below in red, and though Name Manager *is* now showing it as D$56, the actual cell within the sheet is not. It also threw a ton of #VALUE! errors on another tab that utilizes these defined names, and I'm pretty sure it's because the words Product Completion by Mo. are included in the name...

1696974667621.png
1696974719882.png


For i = LBound(arrColumns) To UBound(arrColumns)

For intRow = 1 To 25

strName = arrCodes(i) & intRow

Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)

RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)

With WsList
.Range("A" & Rows.Count).End(xlUp)(2) = strName
.Range("B" & Rows.Count).End(xlUp)(2) = "'" & Ws.Name & "!" & rngAddress.Address
End With

ThisWorkbook.Names.Add Name:=strName, RefersTo:=rngAddress

ThisWorkbook.Names.Add Name:=strName, RefersTo:=RefStr
 
Upvote 0
The only place I see in your code where you are adding/creating names is this statement:

VBA Code:
        ThisWorkbook.Names.Add Name:=strName, RefersTo:=rngAddress


So the way you would add it might be something like this

VBA Code:
    Dim RefStr As String
    For i = LBound(arrColumns) To UBound(arrColumns)

        For intRow = 1 To 25

            strName = arrCodes(i) & intRow

            Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)

            With WsList
                .Range("A" & Rows.Count).End(xlUp)(2) = strName
                .Range("B" & Rows.Count).End(xlUp)(2) = "'" & Ws.Name & "!" & rngAddress.Address
            End With

            RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
            ThisWorkbook.Names.Add Name:=strName, RefersTo:=RefStr

            intCount = intCount + 1

        Next intRow

    Next i
 
Upvote 0
The only place I see in your code where you are adding/creating names is this statement:

VBA Code:
        ThisWorkbook.Names.Add Name:=strName, RefersTo:=rngAddress


So the way you would add it might be something like this

VBA Code:
    Dim RefStr As String
    For i = LBound(arrColumns) To UBound(arrColumns)

        For intRow = 1 To 25

            strName = arrCodes(i) & intRow

            Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)

            With WsList
                .Range("A" & Rows.Count).End(xlUp)(2) = strName
                .Range("B" & Rows.Count).End(xlUp)(2) = "'" & Ws.Name & "!" & rngAddress.Address
            End With

            RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
            ThisWorkbook.Names.Add Name:=strName, RefersTo:=RefStr

            intCount = intCount + 1

        Next intRow

    Next i
In red below is the first one...

For i = LBound(arrColumns) To UBound(arrColumns)

For intRow = 1 To 25

strName = arrCodes(i) & intRow

Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)

RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
 
Upvote 0
The only place I see in your code where you are adding/creating names is this statement:

VBA Code:
        ThisWorkbook.Names.Add Name:=strName, RefersTo:=rngAddress


So the way you would add it might be something like this

VBA Code:
    Dim RefStr As String
    For i = LBound(arrColumns) To UBound(arrColumns)

        For intRow = 1 To 25

            strName = arrCodes(i) & intRow

            Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)

            With WsList
                .Range("A" & Rows.Count).End(xlUp)(2) = strName
                .Range("B" & Rows.Count).End(xlUp)(2) = "'" & Ws.Name & "!" & rngAddress.Address
            End With

            RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
            ThisWorkbook.Names.Add Name:=strName, RefersTo:=RefStr

            intCount = intCount + 1

        Next intRow

    Next i
I put your code where you suggested above and it kept the first $ - $D$56.
 
Upvote 0
In red below is the first one...

For i = LBound(arrColumns) To UBound(arrColumns)

For intRow = 1 To 25

strName = arrCodes(i) & intRow

Set rngAddress = Ws.Cells(55 + intRow, Range(Trim(arrColumns(i)) & "1").Column)

RefStr = Split(rngAddress.Address(1, 0, , 1), "]")(1)
yes
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top