I'm stuck trying to modify my code

Big Lar

Well-known Member
Joined
May 19, 2002
Messages
554
Sheet(“Next”) Cells (A1:A) are populated in an earlier routine
Sheet(“Members”) is a database that has been updated in another routine

Prior to saving the updated project, I wish to add the updated values that exist in Sheet(Members) Column R to all corresponding entries in Sheet(Next) Column B

So:
If Sheet(Next) A1 = "Jones John"


Sheet(Next) B1 = Sheet(Members) “Jones John” iRow 16 value.
Etc…

I have similar code already in my project and thought I knew how to modify it.
But, I’ve been wrestling with this for hours and can’t figure out my error or even if it’s the best solution.
Code:
Const msMembersSheet As String = "Members"
Const msNextSheet As String = "Next"
 
Dim iCol As Integer
Dim lRow As Long, lRow1 As Long
Dim objNames As Object
Dim rCur As Range
Dim sKey As String
Dim wsMembers As Worksheet, wsNext As Worksheet
 
Set objNames = Nothing
Set objNames = CreateObject("Scripting.Dictionary")
Set wsNext = Sheets(msNextSheet)
Set wsMembers = Sheets(msMembersSheet)
 
For Each rCur In Intersect(wsMembers.UsedRange, wsMembers.Columns("C"))
 
    lRow = rCur.Row
    If lRow > 1 Then
        sKey = Trim$(CStr(rCur.Value))
        If sKey <> "" Then
            On Error Resume Next
            objNames.Add Key:=sKey, Item:=lRow
            On Error GoTo 0
        End If
    End If
Next rCur
 
iCol = wsNext.Cells(1, Columns.Count).End(xlToLeft).column - 22
 
 
For Each rCur In Intersect(wsNext.UsedRange, wsNext.Columns("A"))
    lRow = rCur.Row
 
    If lRow > 2 Then
        sKey = Trim$(CStr(rCur.Value))
        If sKey <> "" Then
            lRow1 = 1
            On Error Resume Next
            lRow1 = objNames.Item(sKey)
            On Error GoTo 0
            If lRow1 = 0 Then
                lRow1 = wsNext.Cells(Rows.Count, "A").End(xlUp).Row ' + 1
                wsNext.Range("A" & lRow1).Value = sKey
                'objNames.Add Key:=sKey, Item:=lRow1
            End If
            wsNext.Cells(lRow1, iCol).Value = wsMembers.Range("R" & lRow).Value
          
        End If
    End If
Next rCur
 
objNames.RemoveAll
Set objNames = Nothing
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
Hi Lar your code does not do what you think it does
It does not start from row 1 starts at row 2 the first loop and in 3 the second loop
It does not use column B as stated in "Sheet(Next) B1 = Sheet(Members) “Jones John” iRow 16 value." it uses column C
And it does not match by name, the code is pretty coll thus uses a dictionary but it lacks of GetKey(CreateObject
Cheers
Sergio
 
Upvote 0
Does this do what you need?
Code:
Sub Big_Lar()
   Dim Cl As Range
   Dim sKey As String
   Dim wsMembers As Worksheet, wsNext As Worksheet
    
   Set wsNext = Sheets("Next")
   Set wsMembers = Sheets("pcode")
   
   With CreateObject("scripting.dictionary")
      For Each Cl In wsMembers.Range("C2", wsMembers.Range("C" & Rows.Count).End(xlUp))
         sKey = Trim(Cl.Value)
         If sKey <> "" Then
            .Add sKey, Cl.Offset(, 15).Value
         End If
      Next Cl
   
      For Each Cl In wsNext.Range("A3", wsNext.Range("A" & Rows.Count).End(xlUp))
         sKey = Trim(Cl.Value)
         Cl.Offset(, 1).Value = .Item(sKey)
      Next Cl
   End With
End Sub
 
Upvote 0
Fluff,
Brilliant! Many, many thanks!
You've again saved me from hours of brain damage.
I'm heavily indebted to you.
Big Lar
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,216,113
Messages
6,128,905
Members
449,477
Latest member
panjongshing

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