count & range

Target

New Member
Joined
Apr 23, 2002
Messages
31
Hello
I have a sheet for employee ages & salaries , I want for example (count of employees age between 20-25 years old & the sum salaries amount for this range )
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
On 2002-04-24 03:13, Target wrote:
Hello
I have a sheet for employee ages & salaries , I want for example (count of employees age between 20-25 years old & the sum salaries amount for this range )
Hello Target,
One of the formulas you can use is:
=SUMIF(A:A,">=20",B:B)-SUMIF(A:A,">25",B:B)
Where in column A you have ages and wages in column B.
Eli
 
Upvote 0
Thank I got the sum of the range , the missing part is the count of the range (how many employee between 20-25 years?)
 
Upvote 0
Try this :

="There are "&SUMPRODUCT((A1:A100<26)*(A1:A100>19))&" employees between 20 & 25 years with a total salary of £"&SUMIF(A:A,">=20",B:B)-SUMIF(A:A,">25",B:B)

For the sumproduct to work correctly you must have the size of the two arrays the same.
 
Upvote 0
On 2002-04-24 04:04, Target wrote:
Thank I got the sum of the range , the missing part is the count of the range (how many employee between 20-25 years?)

Sorry,
For count:
=COUNTIF(A:A,">=20")-COUNTIF(A:A,">25")
Eli
 
Upvote 0
Thank you folks I'm almost there , one small condition , how to get the highest salary amount among that range (20-25)?
 
Upvote 0
Here tou go :

=INDIRECT("B"&MAX(ROW(A2:A25)*(A2:A25<=26)*(A2:A25>19)))

Again, you will need to ensure the array ranges are the same.
 
Upvote 0
On 2002-04-24 04:31, Target wrote:
Thank you folks I'm almost there , one small condition , how to get the highest salary amount among that range (20-25)?

Array-enter:

=MAX(IF((A2:A100>=20)*(A2:A100),B2:B100))

In order to array-enter a formula, you need to hit control+shift+enter at the same time, not just enter.

Note. You can't use whole columns in array formulas, something that you can do in SUMIF and COUNTIF formulas (see Eli's replies). I'd suggest using in all these formulas definite ranges (or better dynamic name ranges).

Aladin
 
Upvote 0
Let's not overlook the use of a PivotTable which is well suited for this type of request. Given the following data...

<html><body> <table BORDER=3 CELLSPACING=3 CELLPADDING=3 ><tr><td>Employee</td><td>Age</td><td>Salary</td></tr><tr><td>Larry</td><td>19</td><td>50000</td></tr><tr><td>Jane</td><td>20</td><td>80000</td></tr><tr><td>Tom</td><td>25</td><td>65000</td></tr><tr><td>Joe</td><td>26</td><td>90000</td></tr></table></body></html>

…you’d get…


<html><body> <table BORDER=3 CELLSPACING=3 CELLPADDING=3 ><tr><td></td><td>Data</td><td></td><td></td></tr><tr><td>Age</td><td>Count of Employee</td><td>Sum of Salary</td><td>Max of Salary</td></tr><tr><td>20-25</td><td>2</td><td>145000</td><td>80000</td></tr></table>
 </body></html>
 
Upvote 0

Forum statistics

Threads
1,213,531
Messages
6,114,167
Members
448,554
Latest member
Gleisner2

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