calculate sum and count for each identical values

paupau

New Member
Joined
May 28, 2011
Messages
5
Hi everyone,

I'm new to the forum and using Excel only occasionally. Now I have to calculate something more complex and I really need your help.

I have a sheet with about 170 rows and 130 columns (from which 20 "categories"). I need for each category to find the identical values and calculate for each one the sum and count of the "data" from each column.

I was starting to sort A-Z each category and calculate for each identical value the sum and count of the respective rows. But there are a lot of hours of work ... So any better solution will be greatly appreciated.



example<table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>cat 1</th><th>cat 2</th><th> </th><th>data 1</th><th>data 2</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">a</td><td style=";">x</td><td style="text-align: right;;"></td><td style="text-align: right;;">2.50</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">b</td><td style=";">y</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">5.00</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">a</td><td style=";">z</td><td style="text-align: right;;"></td><td style="text-align: right;;">1.00</td><td style="text-align: right;;">7.00</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">c</td><td style=";">y</td><td style="text-align: right;;"></td><td style="text-align: right;;">3.00</td><td style="text-align: right;;">10.00</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">b</td><td style=";">z</td><td style="text-align: right;;"></td><td style="text-align: right;;">4.25</td><td style="text-align: right;;"></td></tr></tbody></table><br /><br />
expected result<table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>cat 1</th><th>cat 2</th><th> </th><th>data 1</th><th>data 2</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">a sum</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">3.50</td><td style="text-align: right;;">7.00</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">a count</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">2.00</td><td style="text-align: right;;">1.00</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">b sum</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">4.25</td><td style="text-align: right;;">5.00</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">b count</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">1.00</td><td style="text-align: right;;">1.00</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">c sum</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">3.00</td><td style="text-align: right;;">10.00</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">c count</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">1.00</td><td style="text-align: right;;">1.00</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;"></td><td style=";">x sum</td><td style="text-align: right;;"></td><td style="text-align: right;;">2.50</td><td style="text-align: right;;">0.00</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;"></td><td style=";">x count</td><td style="text-align: right;;"></td><td style="text-align: right;;">1.00</td><td style="text-align: right;;">0.00</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;"></td><td style=";">y sum</td><td style="text-align: right;;"></td><td style="text-align: right;;">3.00</td><td style="text-align: right;;">15.00</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: right;;"></td><td style=";">y count</td><td style="text-align: right;;"></td><td style="text-align: right;;">1.00</td><td style="text-align: right;;">2.00</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: right;;"></td><td style=";">z sum</td><td style="text-align: right;;"></td><td style="text-align: right;;">5.25</td><td style="text-align: right;;">7.00</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;"></td><td style=";">z count</td><td style="text-align: right;;"></td><td style="text-align: right;;">2.00</td><td style="text-align: right;;">1.00</td></tr></tbody></table><br /><br />
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
With a little bit twicked leyout:
53404180.jpg


Formulas:
H3:=SUMIF($A$2:$A$6,G3,$D$2:$D$6)
I3:=SUMPRODUCT(--($A$2:$A$6=G3),--($D$2:$D$6<>""))
J3:=SUMIF($A$2:$A$6,G3,$E$2:$E$6)
K3:=SUMPRODUCT(--($B$2:$B$6=G3),--($E$2:$E$6<>""))
copy all down.
Adjust ranges as required.
 
Upvote 0
Thanks Robert for your reply,

Trying your formulas I understand that I need to extract each different category item and change the formula for each data column. But I have about 20 categories with 10 different items and about 110 data columns. This means that I have to write 44000 formulas after extracting the total of about 200 category items.

This is why I was asking for a more automated way of extracting the different category items (I also can manually do this) and the most important to apply both functions automatically for the 110 data columns.
 
Upvote 0
If there is 20 categories and 150 data column how they are related to each other?
I assmued that each category has it's own data column(which will be result I have psoted), but looking back -would product "a" relates only to "data 1" column or more columns in this case how do we know that?
 
Upvote 0
The categories columns are related to data columns by rows. Each category is related to each data column.
I need to have for each category item the sum and count of each data column.

To have it more clear I put the example in one table. Like "cat1" I have about 20; like "data1" about 110; like "a, b, c" about 10 in each category and 160 rows.
<table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">cat 1</td><td style=";">cat 2</td><td style="text-align: right;;"></td><td style=";">data 1</td><td style=";">data 2</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">a</td><td style=";">x</td><td style="text-align: right;;"></td><td style="text-align: right;;">2.50</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">b</td><td style=";">y</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">5.00</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">a</td><td style=";">z</td><td style="text-align: right;;"></td><td style="text-align: right;;">1.00</td><td style="text-align: right;;">7.00</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">c</td><td style=";">y</td><td style="text-align: right;;"></td><td style="text-align: right;;">3.00</td><td style="text-align: right;;">10.00</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">b</td><td style=";">z</td><td style="text-align: right;;"></td><td style="text-align: right;;">4.25</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="color: #FF0000;;">a sum</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">3.50</td><td style="text-align: right;color: #FF0000;;">7.00</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="color: #FF0000;;">a count</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">2.00</td><td style="text-align: right;color: #FF0000;;">1.00</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="color: #FF0000;;">b sum</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">4.25</td><td style="text-align: right;color: #FF0000;;">5.00</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="color: #FF0000;;">b count</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">1.00</td><td style="text-align: right;color: #FF0000;;">1.00</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="color: #FF0000;;">c sum</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">3.00</td><td style="text-align: right;color: #FF0000;;">10.00</td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="color: #FF0000;;">c count</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">1.00</td><td style="text-align: right;color: #FF0000;;">1.00</td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: right;color: #FF0000;;"></td><td style="color: #FF0000;;">x sum</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">2.50</td><td style="text-align: right;color: #FF0000;;">0.00</td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: right;color: #FF0000;;"></td><td style="color: #FF0000;;">x count</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">1.00</td><td style="text-align: right;color: #FF0000;;">0.00</td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: right;color: #FF0000;;"></td><td style="color: #FF0000;;">y sum</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">3.00</td><td style="text-align: right;color: #FF0000;;">15.00</td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: right;color: #FF0000;;"></td><td style="color: #FF0000;;">y count</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">1.00</td><td style="text-align: right;color: #FF0000;;">2.00</td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: right;color: #FF0000;;"></td><td style="color: #FF0000;;">z sum</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">5.25</td><td style="text-align: right;color: #FF0000;;">7.00</td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: right;color: #FF0000;;"></td><td style="color: #FF0000;;">z count</td><td style="text-align: right;color: #FF0000;;"></td><td style="text-align: right;color: #FF0000;;">2.00</td><td style="text-align: right;color: #FF0000;;">1.00</td></tr></tbody></table><br /><br />

The red part is what I need to calculate.
 
Upvote 0
Problem solved with this formulas:

=SUMIF($A$2:$A$6,$A9,D$2:D$6)
=SUMPRODUCT(--($A$2:$A$6=$A10),--(D$2:D$6<>""))

Many thanks to Robert Mika!
 
Upvote 0

Forum statistics

Threads
1,224,583
Messages
6,179,678
Members
452,937
Latest member
Bhg1984

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