vba named range based on row value

littleme

Board Regular
Joined
Nov 15, 2004
Messages
156
Hello!

have been looking around and can't get what I find to really work for me. Need help creating named ranges in VBA.

Data will be sorted by column A.
Data begins on row 2.

Would like for code to identify first instance of a value and the last instance of the value and create a range between them, and 3 columns over. Range name should equal value.

And for the code to work down the column.

Does that make sense?

Any help appreciated
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
What does this mean ? :-

And for the code to work down the column

Is this what you want ? :-

Code:
Dim theValue$, fc As Range, lc As Range
theValue = "whatever"
Set fc = [A:A].Find(What:=theValue, After:=[A1], _
  LookIn:=xlValues, LookAt:=xlWhole, _
  SearchDirection:=xlNext)(1, 4)
If fc Is Nothing Then Exit Sub
Set lc = [A:A].Find(What:=theValue, After:=[A1], _
  LookIn:=xlValues, LookAt:=xlWhole, _
  SearchDirection:=xlPrevious)(1, 4)
Range(fc, lc).Name = theValue
 
Upvote 0
Thank you for your reply!

I havent had a chance to try it yet, but its always good to get a new angle on things. I think I could use it. Realise when i read your answer that I wasn't very specific when i meant "named range". I meant Named Range as the kind you usually create in the spread sheet, using a dialog box.

I work at an architect's office and Named Range is one of the better ways in which our CAD-software can communicate with Excel.

I will give it a whirl and keep you posted!
 
Upvote 0
Perhaps this :-

Code:
Dim rng As range, cel As range, lc As range
[A:A].AdvancedFilter Action:=xlFilterInPlace, Unique:=True
Set rng = range([A2], Cells(Rows.Count, 1).End(xlUp)).SpecialCells(xlCellTypeVisible)
ActiveSheet.ShowAllData
For Each cel In rng
    Set lc = [A:A].Find(What:=cel, After:=[A1], _
        LookIn:=xlValues, LookAt:=xlWhole, _
        SearchDirection:=xlPrevious)(1, 4)
    range(cel(1, 4), lc).Name = cel
Next
 
Upvote 0
Hi!

Worked a bit over the weekend and got something that does what I need.
Thank you Boller for helping me look at the problem from a different angle =) What I have ended up with is (Suggestions for improvement welcome):

Option Explicit

Dim FL As Integer
Dim FF As Integer
Dim FindString As String
Dim wb As Workbook
Dim ws1 As Worksheet
Dim ws2 As Worksheet
Dim StartRng As Range
Dim EndRng As Range
Dim Rng As Range
Dim LastRow As Long
Dim i As Long
Dim NamedRng As String
Sub Klar()

Set wb = ActiveWorkbook
Set ws1 = Worksheets("Blad1")
Set ws2 = Worksheets("Blad2")
Set StartRng = ws2.Range("A1")
Set EndRng = ws1.Range("A1")

Application.ScreenUpdating = False
With ws1
LastRow = .Cells(.Rows.Count, "A").End(xlUp).Row
ws1.Range("A2:A" & LastRow).Copy
Application.Goto StartRng
Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
:=False, Transpose:=False
End With
With ws2
ws2.Range("A:A").RemoveDuplicates Columns:=1, Header:=xlNo
Application.CutCopyMode = False

LastRow = .Cells(.Rows.Count, "A").End(xlUp).Row

Application.Goto StartRng

For i = 1 To LastRow
FindString = ActiveCell.Value
With ws1.Range("A:A")
Set Rng = .Find(What:=FindString, _
After:=.Cells(.Cells.Count), _
LookIn:=xlValues, _
LookAt:=xlWhole, _
SearchOrder:=xlByRows, _
SearchDirection:=xlNext, _
MatchCase:=False)
If Not Rng Is Nothing Then
Application.Goto Rng, True
FF = ActiveCell.Row
Set Rng = .Find(What:=FindString, _
After:=.Cells(1), _
LookIn:=xlValues, _
LookAt:=xlWhole, _
SearchOrder:=xlByRows, _
SearchDirection:=xlPrevious, _
MatchCase:=False)
Application.Goto Rng, True
FL = ActiveCell.Row

NamedRng = "TR_" & ActiveCell.Value

wb.Names.Add Name:=NamedRng, _
RefersToR1C1:="=R" & FF & "C" & 2 & ":INDEX(C" & 3 & "," & FL & ")"
Application.Goto Reference:=NamedRng
'With Selection.Interior
'.Pattern = xlSolid
'.PatternColorIndex = xlAutomatic
'.ThemeColor = xlThemeColorDark1
'.TintAndShade = -0.249977111117893
'.PatternTintAndShade = 0
'End With
Else
MsgBox ("TR. " & ActiveCell.Value & " hittades inte!")
ActiveCell.Interior.Color = 49407
End If
End With
Application.Goto StartRng.Offset(i, 0)
Next i
End With

Application.ScreenUpdating = True
Application.Goto EndRng
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,544
Messages
6,114,239
Members
448,555
Latest member
RobertJones1986

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