If Statement Within VLOOKUP

SCWI

New Member
Joined
Jul 24, 2007
Messages
7
Hello...

I was wondering if anyone could help me with a VLOOKUP issue. Here is the equation that I have, which works fine: VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,FALSE). My question is, how can I add an if statement to this equation so that if the VLOOKUP does not find a match the cell is left blank and doesn't list #N/A. Thanks for your help.
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.

Lewiy

Well-known Member
Joined
Jan 5, 2007
Messages
4,284
Try this:
Code:
=IF(COUNTIF('25 Client Revenue'!$A$1:$B$1521,A4)=0,"",VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,FALSE))
 

vranjit138

Board Regular
Joined
Dec 18, 2006
Messages
141
Hi to avoid the #N/A use the vlookup as

=if(isna(vlookup(_____________),0,vlookup(__________))

whereever the vlookup does not find the match it will return 0
and you will not get #N/A

Regards
Ranjit
 

vranjit138

Board Regular
Joined
Dec 18, 2006
Messages
141
Hi to avoid the #N/A use the vlookup as

=if(isna(vlookup(_____________)),0,vlookup(__________))

whereever the vlookup does not find the match it will return 0
and you will not get #N/A

Regards
Ranjit
 

njimack

Well-known Member
Joined
Jun 17, 2005
Messages
7,764

ADVERTISEMENT

Lewiy's formula can be slightly shortened, since a COUNTIF that returns 0 evaluates to FALSE. So...

=IF(COUNTIF('25 Client Revenue'!$A:$A,A4),VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,FALSE),"")
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,209
Hello...

I was wondering if anyone could help me with a VLOOKUP issue. Here is the equation that I have, which works fine: VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,FALSE). My question is, how can I add an if statement to this equation so that if the VLOOKUP does not find a match the cell is left blank and doesn't list #N/A. Thanks for your help.

On Excel 2007...

=IFERROR(VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,0),"")

On prior versions...

1]

B4:

=IF(ISNA(C4),"",C4)

C4:

=VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,0)

2]

Code:
=IF(ISNUMBER(MATCH(A4,'25 Client Revenue'!$A$1:$A$1521,0)),
      VLOOKUP(A4,'25 Client Revenue'!$A$1:$B$1521,2,0),
      "")

which is faster than one with a CountIf test.

3]

If '25 Client Revenue'!$A$1:$B$1521 is sorted in ascending order...

Code:
=IF(LOOKUP(A4,'25 Client Revenue'!$A$1:$A$1521)=A4,
      LOOKUP(A4,'25 Client Revenue'!$A$1:$A$1521,
                        '25 Client Revenue'!$B$1:$B$1521)
      "")

would perform even better.
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,152,161
Messages
5,768,539
Members
425,480
Latest member
br400821

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
Top