Loop through cells and update with a VLookup formula using VBA

edwardj3

New Member
Joined
Jan 16, 2018
Messages
41
Office Version
  1. 365
Platform
  1. Windows
Hi all. Hope you guys can help me out.

Got a VBA process which imports data from a web page and clears cells where the value is less than 0. This works fine so the result is like below. Data in cells A4:C15

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]114[/TD]
[TD]sev1[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]114[/TD]
[TD]sev2[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]114[/TD]
[TD]sev3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]125[/TD]
[TD]sev1[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]125[/TD]
[TD]sev2[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]125[/TD]
[TD]sev3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]137[/TD]
[TD]sev1[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]137[/TD]
[TD]sev2[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]137[/TD]
[TD]sev3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]148[/TD]
[TD]sev1[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]148[/TD]
[TD]sev2[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]148[/TD]
[TD]sev3[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

The next step is to populate the cells which have been cleared with a value from another table/area in the same worksheet. The table below is in B34:C37. The value in column 2 can change on a daily basis so I can't hard-code a value.

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]114[/TD]
[TD]100[/TD]
[/TR]
[TR]
[TD]125[/TD]
[TD]200[/TD]
[/TR]
[TR]
[TD]137[/TD]
[TD]300[/TD]
[/TR]
[TR]
[TD]148[/TD]
[TD]400[/TD]
[/TR]
</tbody>[/TABLE]

I've looked around the web and I think I can should be using a loop to go through a range, ignore the cells with a 0 but if the cell is empty I then need to populate it with the appropriate value e.g. the black cell which has 114 would be updated with 100, the blank cell with 125 would be populated with 200 and so on. I think WorksheetFunction.VLookup is what I need or a possible solution but this is above my current knowledge/expertise.

Advice and hopefully a solution would be appreciated.

Thanks
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
I've looked around the web and I think I can should be using a loop to go through a range, ignore the cells with a 0 but if the cell is empty I then need to populate it with the appropriate value e.g. the black cell which has 114 would be updated with 100, the blank cell with 125 would be populated with 200 and so on. I think WorksheetFunction.VLookup is what I need or a possible solution but this is above my current knowledge/expertise.

I don't know how to use vlookup in vba, but this code should do the same:

Code:
[B][COLOR=Royalblue]Sub[/COLOR][/B] a1076689a()
[I][COLOR=seagreen]'https://www.mrexcel.com/forum/excel-questions/1076689-loop-through-cells-update-vlookup-formula-using-vba.html[/COLOR][/I]
[B][COLOR=Royalblue]Dim[/COLOR][/B] c [B][COLOR=Royalblue]As[/COLOR][/B] Range
[B][COLOR=Royalblue]Dim[/COLOR][/B] d [B][COLOR=Royalblue]As[/COLOR][/B] [B][COLOR=Royalblue]Object[/COLOR][/B]

    [B][COLOR=Royalblue]Set[/COLOR][/B] d = CreateObject([COLOR=brown]"scripting.dictionary"[/COLOR])

    [B][COLOR=Royalblue]For[/COLOR][/B] [B][COLOR=Royalblue]Each[/COLOR][/B] c [B][COLOR=Royalblue]In[/COLOR][/B] Range([COLOR=brown]"B34:B37"[/COLOR])
        d([B][COLOR=Royalblue]CStr[/COLOR][/B](c)) = c.Offset(, [COLOR=crimson]1[/COLOR])
    [B][COLOR=Royalblue]Next[/COLOR][/B] c
    
    [B][COLOR=Royalblue]For[/COLOR][/B] [B][COLOR=Royalblue]Each[/COLOR][/B] c [B][COLOR=Royalblue]In[/COLOR][/B] Range([COLOR=brown]"C4:C15"[/COLOR])
        [B][COLOR=Royalblue]If[/COLOR][/B] c = [COLOR=brown]""[/COLOR] [B][COLOR=Royalblue]Then[/COLOR][/B]
        c = d([B][COLOR=Royalblue]CStr[/COLOR][/B](c.Offset(, -[COLOR=crimson]2[/COLOR])))
        [B][COLOR=Royalblue]End[/COLOR][/B] [B][COLOR=Royalblue]If[/COLOR][/B]
    [B][COLOR=Royalblue]Next[/COLOR][/B] c

[B][COLOR=Royalblue]End[/COLOR][/B] [B][COLOR=Royalblue]Sub[/COLOR][/B]
 
Upvote 0
Thank you Akuini. That worked perfectly. Way above my current VBA capability. What does CreateObject("scripting.dictionary") do?
 
Upvote 0
Thank you Akuini. That worked perfectly. Way above my current VBA capability. What does CreateObject("scripting.dictionary") do?

About Dictionary object you can read a good article here:
https://www.experts-exchange.com/articles/3391/Using-the-Dictionary-Class-in-VBA.html

Actually I just learnt how to use vlookup in vba, it's even simpler to accomplish your task above than using Dictionary.
Here's the code:

Code:
Sub a1076689c()
'https://www.mrexcel.com/forum/excel-questions/1076689-loop-through-cells-update-vlookup-formula-using-vba.html
Dim c As Range
    For Each c In Range("C4:C15")
        If c = "" Then
        c = WorksheetFunction.VLOOKUP(c.Offset(, -2), Range("B34:C37"), 2, False)
        End If
    Next c
End Sub
 
Upvote 0
Thanks again Akuini. That is the function I'd seen in other solutions but couldn't work out how to apply in a For loop. Sure I'll be able to apply this in other processes. Regards
 
Upvote 0
You're welcome & thanks for replying
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,875
Members
452,363
Latest member
merico17

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