+ Reply to Thread
Results 1 to 17 of 17

average over worksheets excluding zeros

  1. #1
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    average over worksheets excluding zeros

    im trying to average over a number of work sheets to determine the avergage talk time of employees over a day, ive tried:

    Please Login or Register  to view this content.
    Were Persons name is the name of the worksheet and h16 is the cell i wish to average, i keep getting a value error or simply that it wont work, i understand that i can use a vba to do this although i am not familliar with this is there another way to average the time over a number of worksheets? i know i could just remove the zeros from the cells but the info in them is taken from another sheet so it is not possible to do that.

    Thanks Scott

  2. #2
    Registered User
    Join Date
    08-04-2009
    Location
    Brussels, Belgium
    MS-Off Ver
    Excel 2003
    Posts
    54

    Re: average over worksheets excluding zeros

    I think that you need to do average(personsnameCell,ppersonsnameCell,personsnameCell,personsnameCell) instead of average(personsnameCell:personsnameCell). Basically select the cell you want in a sheet, type "," select the next cell on the next sheet and so on.

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    Is the person's name separated with spaces?

    Try:

    =IF(ISERROR(AVERAGE('persons name:persons name'!h16)),"",AVERAGE('Persons name:persons name'!h16))

    Note the apostrophe's
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  4. #4
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: average over worksheets excluding zeros

    If as you say the Average is conditional (exclude zero H16 values) then if you're not prepared to utilise a Helper on each sheet then you're looking at pretty expensive / volatile SUMPRODUCT / Array formulae.

    John McGimpsey has a page outlining a variety of approaches for conditional 3D calculations: http://www.mcgimpsey.com/excel/threedsumif.html

    All of which can be adapted to conduct an Average - ie 3D SUM / 3D COUNTIF (<>0)

  5. #5
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    I took it as the OP is getting Div/0 error when the cells all have 0's or are blank..... and is trying to not have that error display...

  6. #6
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    Re: average over worksheets excluding zeros

    thanks for the quick replies! the formula is as you suggested NBVC but just get a VALUE error, looks like it will need to be the 3D conditional formulas just need to create one that will do the job, if anyone has a pointer were to start id be greatful.

    regards Scott

  7. #7
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    Can you explain exactly what you need... ie. what is being averaged and based on what conditions, etc.

  8. #8
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    Re: average over worksheets excluding zeros

    im trying to average, the average talk time across a team. in h16 of each individuals sheet is there talk time for the day in h16 on the summary sheet is the average for the team, some people work part time or are off. i know i could just delete the zero to get the average but the individuals average talk time is taken from another source so i cannot delete the formula out.hope this makes sense

    Thanks scott

  9. #9
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    To best describe or illustrate your problem you would be better off attaching a dummy workbook, the workbook should contain the same structure and some dummy data of the same type as the type you have in your real workbook - so, if a cell contains numbers & letters in this format abc-123 then that should be reflected in the dummy workbook.

    If needed supply a before and after sheet in the workbook so the person helping you can see what you are trying to achieve.

    Doing this will ensure you get the result you need!

  10. #10
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    Re: average over worksheets excluding zeros

    i tired to add one with my last post but keep getting a forum database error

  11. #11
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    Try zipping it.. and keep the size below the allowable limit

  12. #12
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    Re: average over worksheets excluding zeros

    here is a dummy file i need an average talk time in the summary sheet for the average talk time for the team thanks
    Attached Files Attached Files

  13. #13
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    Want to make sure I understand...

    ... if I enter this formula:

    =AVERAGE('SPARE 1:SPARE 6'!H16)

    I get a result, even if all H16 cells are 0... I get 0....

    Am I misunderstanding you?

  14. #14
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    Re: average over worksheets excluding zeros

    no your understanding right and given my first post with the forumula thats what i expected it to be but i need it to exclude cells with a zero, thought an if is error would work but doesnt any ideas how to get an average of the teams talktime and exclude 0 were people werent in on that day etc i.e i need it to average the cells with an value in and ignore it if it contains a zero. hope this makes sense and thanks for you help so far

  15. #15
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    Ok. See attached.

    First, if your actual sheet names do not have the pattern you show or similar... like if they are totally different, then list the sheetnames in your summary sheet somewhere... see P1:P6.. then name that list something like "TabNames", through Insert|Name|Define.

    Then use formula:

    Please Login or Register  to view this content.
    See H16.


    If your sheets are named in a pattern similar to your sample, then no need to create a list and named range... just use formula as per:

    Please Login or Register  to view this content.
    See P16.
    Attached Files Attached Files

  16. #16
    Registered User
    Join Date
    02-12-2009
    Location
    liverpool, england
    MS-Off Ver
    Excel 2003
    Posts
    16

    Re: average over worksheets excluding zeros

    hi thanks for the reply ive tried the way you suggested (the first one as the sheets are peoples names) however as people leave and new people join the company the names on the sheets changes, so i dont think it will work in the long run. is there anyother way of doing it so that if the names of the sheet change it would still work? thanks for your help

  17. #17
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: average over worksheets excluding zeros

    An alternative that would work would be to install a free addin called Morefunc.xll from here: Morefunc


    Then insert a blank sheet before all the named sheets and call this sheet 'Start' and insert another sheet just before your summary sheet and after all the named sheets and call this 'End' (without the quotes).

    Then apply formula below:

    =SUMPRODUCT(--(THREED(Start:End!H16)<>0),THREED(Start:End!H16))/SUMPRODUCT(--(THREED(Start:End!H16)<>0))

    Now you can add and delete sheet between these "bookends" as you desire.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1