Thanks Thanks:  0
Likes Likes:  0
Results 1 to 8 of 8

Thread: #N/A

  1. #1
    Board Regular
    Join Date
    Feb 2002
    Posts
    155
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

  2. #2
    MrExcel MVP Anne Troy's Avatar
    Join Date
    Feb 2002
    Location
    Westwood NJ
    Posts
    2,582
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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.
    ~Anne Troy

  3. #3
    Board Regular
    Join Date
    Feb 2002
    Location
    North Alabama, USA
    Posts
    105
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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 ]

  4. #4
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    83,586
    Post Thanks / Like
    Mentioned
    30 Post(s)
    Tagged
    6 Thread(s)

    Default

    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 ]

  5. #5
    Rest in Peace
    Join Date
    Feb 2002
    Posts
    1,582
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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.




  6. #6
    Board Regular
    Join Date
    Feb 2002
    Location
    Calgary, Alberta Canada
    Posts
    3,422
    Post Thanks / Like
    Mentioned
    1 Post(s)
    Tagged
    0 Thread(s)

    Default



    Daverage alternative

    What if there are some negative numbers
    in the range?

  7. #7
    Rest in Peace
    Join Date
    Feb 2002
    Posts
    1,582
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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


    [ This Message was edited by: Dave Hawley on 2002-03-16 12:39 ]

  8. #8
    Rest in Peace
    Join Date
    Feb 2002
    Posts
    1,582
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    You may also be interested in some slightly more advanced uses of the Database Functions, you can download a free Workbook here if you are:

    http://www.ozgrid.com/download/default.htm
    DFunctionsWithValidation.zip




Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •