#N/A

royhern

Board Regular
Joined
Feb 21, 2002
Messages
158
have Vlookup formula that returns values which includes #N/A and numbers that must be average. When i take average it returns #N/A again as a total average. How can i bypass this ?

Thanks, Roy
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Have you tried retyping either the numbers that are being looked up or the numbers in the list that needs to match? Sometimes, Excel doesn't see numbers as values, but as text.
 
Upvote 0
There is a special function called isna(). Place your vlookup inside and test isna() with an if. For example:

:"=if(isna(vlookup(a1,c1:z20,2,false)),0,vlookup(a1,c1:z20,2,false))"

HTH
Rocky
Woops I just reread your post. The zeros will mess the average up. You are going to have to sum()/countif(b1:b20,">0") to figure the average. Unless someone has a better way.
Sorry...
Rocky
This message was edited by Rocky E on 2002-03-15 18:44
This message was edited by Rocky E on 2002-03-15 18:54
 
Upvote 0
On 2002-03-15 18:31, royhern wrote:
have Vlookup formula that returns values which includes #N/A and numbers that must be average. When i take average it returns #N/A again as a total average. How can i bypass this ?

Thanks, Roy

Roy,

You don't have to suppress #N/A's that VLOOKUP returns in order to compute an average:

Lets say that we have the following in A1:A4.

The following formula will compute the desired average:

=SUMIF(A1:A4,"<>#N/A")/MAX(1,COUNTIF(A1:A4,"<>#N/A"))

Addendum: It has been noticed that COUNTIF will not ignore any blanks in the range, because of its condition/criterion part. The observation is correct. The original formula requires modification:

=SUMIF(A1:A4,"<>#N/A")/MAX(1,COUNT(A1:A4))

which I should have suggested in the first place.

Aladin
This message was edited by Aladin Akyurek on 2002-03-16 03:49
 
Upvote 0
Hi Roy

You will get the correct result by using the DAVERAGE Function, this will ignore #N/A and blank cells by default. the method above doesn't ingnore blanks and can easily give an incorrect result.

Let's say your numbers are in the Range A1:A10 and A1 has a heading of "Nums"

Copy this heading to cell D1 then in D2 put:
>0

Now simply use:

=DAVERAGE(A1:A10,"Nums",D1:D2)

This will give you the correct result. The Dfunctions (IMO) are very much underutilized and can perform very complicated functions ob very large data tables that need to meet multiple criteria. Once you get the hang of them you will never consider an array formula again.
 
Upvote 0
Daverage alternative

What if there are some negative numbers
in the range?
 
Upvote 0
Then you simply add another criteria and modify the first.

Eg, with the copied heading now in D1 and E1
Put:<>0 in D2 and<>#N/A in E2

The reason we now need to tell our DAVERAGE to ingnore #N/A (does normally by default) is because we are now forcing it to include it by using #N/A



_________________
Kind Regards
Dave Hawley
OzGrid Business Applications
Microsoft Excel/VBA Training
OzGrid.BusApp.170x45.gif

This message was edited by Dave Hawley on 2002-03-16 12:39
 
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,952
Members
448,535
Latest member
alrossman

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