VBA for lookup

maarten_zee

New Member
Joined
Jan 27, 2004
Messages
8
Given the following sheets...

VJP
output+25-01-04.xls
ABCD
1Voorafgaandejournaalposten
2RubriekRekeningNaam
3Rubriek_11110
4Rubriek_44610
5Rubriek_11420
6Rubriek_33000
7Rubriek_66004
8Rubriek_66004
VJP


InputFromKing
output+25-01-04.xls
ABCD
1RekeningNaam
20010Aandelenkapitaal
30230Inventariseninrichting
40240Computersenrandapperatuur
50250Intrenrtransport
60810Leninging
70820Leaseverplichting
InputFromKing


I'd like to look up "Naam" associated with the value in B3 on VJP from InputFromKing by means of VBA code. If nothing found, I'd like the following message to appear instead:<Vul hier een omschrijving of een naam>.

Thanks in advance.
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
Howdy maarten_zee,

Heres something to get you started. Its the vba version but I'm sure there are many here who can share how to do it via formula or excel function as well.

Code:
Sub MyLookup()
Dim K As Single, L As Single, LastRow1 As Single, LastRow2 As Single
Dim MyData As Worksheet
Set MyData = Sheets("InputFromKing")
Sheets("VJP").Activate
LastRow1 = Range("B65536").End(xlUp).Row
LastRow2 = Sheets("InputFromKing").Range("A65536").End(xlUp).Row

For K = 3 To LastRow1
For L = 2 To LastRow2
If Cells(K, 2) = MyData.Cells(L, 1) Then Cells(K, 3) = MyData.Cells(L, 2)
Next L
Next K
End Sub

HTH
 
Upvote 0
There is something missing:

I'd like the following message to appear instead:"Vul hier een omschrijving in"

Egress thanx for your reply, I have found still no time to test the code but if it works I'll let you no.

Mrt
 
Upvote 0
Code:
Sub Macro2()
lastRow = Sheets("VJP").Range("b3").End(xlDown).Row
Sheets("VJP").Range("c3:c" & lastRow).FormulaR1C1 = _
        "=IF(ISNA(VLOOKUP(RC[-1],InputFromKing!C[-2]:C[-1],2,0)),""Vul hier een omschrijving in"",VLOOKUP(RC[-1],InputFromKing!C[-2]:C[-1],2,0))"
End Sub

Does this help?
 
Upvote 0
maarten_zee said:
I have found still no time to test the code but if it works I'll let you no.
Not very kindly for Egress1, who spent time at your problem.
To test his code, it takes only 1 minute....
Both Egress1' solutions work perfectly !
 
Upvote 0
Ok, finally...

Put this code in the VJP sheet (Right click on the sheet tab, choose View code, and paste it there)

<font face=Courier New><SPAN style="color:#00007F">Private</SPAN> <SPAN style="color:#00007F">Sub</SPAN> Worksheet_Change(<SPAN style="color:#00007F">ByVal</SPAN> Target <SPAN style="color:#00007F">As</SPAN> Range)
    <SPAN style="color:#00007F">If</SPAN> Target.Column = 2 <SPAN style="color:#00007F">Then</SPAN>   <SPAN style="color:#007F00">'Is it an entry in column B</SPAN>
        <SPAN style="color:#00007F">Dim</SPAN> Ans <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Variant</SPAN>
        <SPAN style="color:#00007F">Dim</SPAN> Rng <SPAN style="color:#00007F">As</SPAN> Range
        
        <SPAN style="color:#007F00">'Did the user make an entry ?</SPAN>
        <SPAN style="color:#00007F">If</SPAN> Len(Target.Value) = 0 <SPAN style="color:#00007F">Then</SPAN> <SPAN style="color:#00007F">Exit</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
        
        <SPAN style="color:#00007F">With</SPAN> Sheets("InputFromKing")    <SPAN style="color:#007F00">'Define the lookup range</SPAN>
            <SPAN style="color:#00007F">Set</SPAN> Rng = .Range("A2", .Range("A65536").End(xlUp))
        <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN>
        
        
        <SPAN style="color:#007F00">'Search for the changed cell in VJP</SPAN>
        Ans = Application.Match(Target.Text, Rng, 0)
        
        <SPAN style="color:#007F00">'Did we find it ?</SPAN>
        <SPAN style="color:#00007F">If</SPAN> IsNumeric(Ans) <SPAN style="color:#00007F">Then</SPAN>
            Application.EnableEvents = <SPAN style="color:#00007F">False</SPAN>    <SPAN style="color:#007F00">'Turn events off</SPAN>
            Target.Offset(, 1).Value = Rng(Ans).Offset(, 1).Value   <SPAN style="color:#007F00">'Put the associated Naam</SPAN>
            Application.EnableEvents = <SPAN style="color:#00007F">True</SPAN>    <SPAN style="color:#007F00">'Turn events on</SPAN>
        <SPAN style="color:#00007F">Else</SPAN>
            Ans = ""        <SPAN style="color:#007F00">'To convert the variable to a string</SPAN>
            
            <SPAN style="color:#007F00">'Ok, it's not on the list, so, let's warn the user</SPAN>
            Ans = InputBox("Vul  hier de omschrijving in", "Vul  hier de omschrijving in", "")
            
            <SPAN style="color:#007F00">'Did the user enter something there ?</SPAN>
            <SPAN style="color:#00007F">If</SPAN> Len(Ans) = 0 <SPAN style="color:#00007F">Then</SPAN>
                <SPAN style="color:#007F00">'Cancelled or didn't enter anything</SPAN>
                <SPAN style="color:#007F00">'so, delete the current entry and exit the code</SPAN>
                Application.EnableEvents = <SPAN style="color:#00007F">False</SPAN>
                <SPAN style="color:#00007F">On</SPAN> <SPAN style="color:#00007F">Error</SPAN> <SPAN style="color:#00007F">Resume</SPAN> <SPAN style="color:#00007F">Next</SPAN>
                Application.Undo
                Application.EnableEvents = <SPAN style="color:#00007F">True</SPAN>
                <SPAN style="color:#00007F">Exit</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
            End <SPAN style="color:#00007F">If</SPAN>
            
            <SPAN style="color:#007F00">'Put the Naam</SPAN>
            Application.EnableEvents = <SPAN style="color:#00007F">False</SPAN>    <SPAN style="color:#007F00">'Turn events off</SPAN>
            Target.Offset(, 1).Value = Ans
            Application.EnableEvents = <SPAN style="color:#00007F">True</SPAN>    <SPAN style="color:#007F00">'Turn events on</SPAN>
            
            <SPAN style="color:#007F00">'Store the Rekening and the Naam in InputFromKing</SPAN>
            <SPAN style="color:#00007F">With</SPAN> Sheets("InputFromKing").Range("A65536").<SPAN style="color:#00007F">End</SPAN>(xlUp)
                .Value = "'" & Target.Value     <SPAN style="color:#007F00">'Make sure its entered as a text</SPAN>
                .Offset(, 1).Value = Ans
            <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN>
        <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
        
    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
End <SPAN style="color:#00007F">Sub</SPAN>
</FONT>
 
Upvote 0

Forum statistics

Threads
1,214,819
Messages
6,121,741
Members
449,050
Latest member
excelknuckles

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