SUMIF On Column Where Single Column is Primary Key for Numerous Criteria?

PacSum

New Member
Joined
Jan 8, 2017
Messages
30
I couldn't come up with a clear title. Here's the question with a proper example.

Two Tables of Data:

TABLE A
NameGPMPAR
James8030402320880480
Steph7224481800576288
Kevin7325551971511511
Chris7827301404780234
Patrick8032001760160960

<tbody>
</tbody>

TABLE B
NameTeamPosition
JamesHoustonForward
StephWarriorsGuard
KevinWarriorsForward
ChrisHoustonGuard
PatrickNew YorkCenter

<tbody>
</tbody>

I want to do SUMIF statements on Table A.

I want the SUM of all P for Names on Team Houston. We can look at Table B and see that this would be James and Chris. So this should be 2320+1404.

The simple way would be to aggregate all data into a single table, but that would get quite messy since there is a lot more data than shown in the example.

Any ideas? Thanks in advance!
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Try


A
B
C
D
E
F
G
H
I
J
1
Name​
GP​
M​
P​
A​
R​
Crit1​
Crit2​
Result​
2
James​
80​
3040​
2320​
880​
480​
P​
Houston​
3724​
3
Steph​
72​
2448​
1800​
576​
288​
4
Kevin​
73​
2555​
1971​
511​
511​
5
Chris​
78​
2730​
1404​
780​
234​
6
Patrick​
80​
3200​
1760​
160​
960​
7
8
9
Name​
Team​
Position​
10
James​
Houston​
Forward​
11
Steph​
Warriors​
Guard​
12
Kevin​
Warriors​
Forward​
13
Chris​
Houston​
Guard​
14
Patrick​
New York​
Center​
15

Criteria in H2:I2

Array formula in J2
=SUM(SUMIF(A$2:A$6,IF(B$10:B$14=I2,A$10:A$14),INDEX(B$2:F$6,0,MATCH(H2,B$1:F$1,0))))
confirmed with Ctrl+Shift+Enter, not just Enter

M.
 
Upvote 0
Try


A
B
C
D
E
F
G
H
I
J
1
Name​
GP​
M​
P​
A​
R​
Crit1​
Crit2​
Result​
2
James​
80​
3040​
2320​
880​
480​
P​
Houston​
3724​
3
Steph​
72​
2448​
1800​
576​
288​
4
Kevin​
73​
2555​
1971​
511​
511​
5
Chris​
78​
2730​
1404​
780​
234​
6
Patrick​
80​
3200​
1760​
160​
960​
7
8
9
Name​
Team​
Position​
10
James​
Houston​
Forward​
11
Steph​
Warriors​
Guard​
12
Kevin​
Warriors​
Forward​
13
Chris​
Houston​
Guard​
14
Patrick​
New York​
Center​
15

<tbody>
</tbody>


Criteria in H2:I2

Array formula in J2
=SUM(SUMIF(A$2:A$6,IF(B$10:B$14=I2,A$10:A$14),INDEX(B$2:F$6,0,MATCH(H2,B$1:F$1,0))))
confirmed with Ctrl+Shift+Enter, not just Enter

M.

Absolutely perfect. Thank you!
 
Upvote 0

Forum statistics

Threads
1,214,793
Messages
6,121,617
Members
449,039
Latest member
Mbone Mathonsi

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