A Microsoft Excel forum. ExcelBanter

If this is your first visit, be sure to check out the FAQ by clicking the link above. You may have to register before you can post: click the register link above to proceed. To start viewing messages, select the forum that you want to visit from the selection below.

Go Back   Home » ExcelBanter forum » Excel Newsgroups » Excel Worksheet Functions
Site Map Home Register Authors List Search Today's Posts Mark Forums Read Web Partners

Calculating Average Length of Service



 
 
Thread Tools Display Modes
  #1  
Old September 4th 08, 05:11 PM posted to microsoft.public.excel.worksheet.functions
EasyPeasy
external usenet poster
 
Posts: 1
Default Calculating Average Length of Service

I've got a spreadsheet that includes 3 columns with range names of 'gender'
(containing either M or F), 'age' and 'company_service' (both expressed as
years).

I want to be able to calculate the average length of service for men and
women separately based on age bands (eg between 21 and 30).

Can someone please start me off with a formula that can handle one set of
conditions from which I can hopefully work out the rest. eg :

Lower Age Band 21
Upper Age Band 30
Gender M

Thanks





Ads
  #2  
Old September 4th 08, 05:45 PM posted to microsoft.public.excel.worksheet.functions
Gary''s Student
external usenet poster
 
Posts: 11,059
Default Calculating Average Length of Service

Divide the total years of service of the selected subgroup by the number of
individuals in the subgroup:

=SUMPRODUCT(--(A1:A100="M"),--(B1:B100>20),--(B1:B100<31),C1:C100)/SUMPRODUCT(--(A1:A100="M"),--(B1:B100>20),--(B1:B100<31))

for for data like:

F 38 3
F 32 4
F 38 7
F 31 5
F 27 6
F 32 3
M 40 5
M 38 3
M 30 1
M 20 5
F 23 6
F 26 2
M 27 6
F 30 4
M 27 4
M 37 4
F 20 7
F 23 2
F 38 1
M 22 6
M 30 4
F 20 4
M 29 1
F 33 5
M 30 3
F 29 4
F 23 4
F 39 7
M 34 6
F 25 1

for fomula returns 3.571428571

--
Gary''s Student - gsnu2007k


"EasyPeasy" wrote:

> I've got a spreadsheet that includes 3 columns with range names of 'gender'
> (containing either M or F), 'age' and 'company_service' (both expressed as
> years).
>
> I want to be able to calculate the average length of service for men and
> women separately based on age bands (eg between 21 and 30).
>
> Can someone please start me off with a formula that can handle one set of
> conditions from which I can hopefully work out the rest. eg :
>
> Lower Age Band 21
> Upper Age Band 30
> Gender M
>
> Thanks
>
>
>
>
>
>

  #3  
Old September 4th 08, 06:26 PM posted to microsoft.public.excel.worksheet.functions
Teethless mama
external usenet poster
 
Posts: 3,718
Default Calculating Average Length of Service

XL-2007:
=AVERAGEIFS(C1:C100,A1:A100,"M",B1:B100,">20",B1:B 100,"<31")
just press ENTER


Earlier versions:

=AVERAGE(IF((A1:A100="M")*(B1:B100>20)*(B1:B100<31 ),C1:C100))
ctrl+shift+enter, not just ENTER


"EasyPeasy" wrote:

> I've got a spreadsheet that includes 3 columns with range names of 'gender'
> (containing either M or F), 'age' and 'company_service' (both expressed as
> years).
>
> I want to be able to calculate the average length of service for men and
> women separately based on age bands (eg between 21 and 30).
>
> Can someone please start me off with a formula that can handle one set of
> conditions from which I can hopefully work out the rest. eg :
>
> Lower Age Band 21
> Upper Age Band 30
> Gender M
>
> Thanks
>
>
>
>
>
>

 




Thread Tools
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

vB code is On
Smilies are On
[IMG] code is On
HTML code is Off
Forum Jump

Similar Threads
Thread Thread Starter Forum Replies Last Post
calculating a formula for a service level Andy B Excel Worksheet Functions 1 August 2nd 07 12:20 PM
calculating a formula for a service level Andy B Excel Worksheet Functions 1 August 2nd 07 09:07 AM
Length of service calculated in calender months. Dave Excel Discussion (Misc queries) 2 February 23rd 07 07:42 AM
Length of Service Dom Excel Worksheet Functions 7 July 17th 06 10:47 PM
calculating service dates Tanya Excel Worksheet Functions 2 January 3rd 05 08:15 PM


All times are GMT +1. The time now is 06:28 PM.


Powered by vBulletin® Version 3.6.4
Copyright ©2000 - 2014, Jelsoft Enterprises Ltd.
Copyright 2004-2014 ExcelBanter.
The comments are property of their posters.