Sumifs where columns are transposed and contain duplicate labels

drluke

Active Member
Joined
Apr 17, 2014
Messages
314
Office Version
  1. 365
Platform
  1. Windows
How can I do a SUMIFS (or similar) where columns/rows are transposed and columns have the same label (like B&D below). In my data sheet data is organised like:

[TABLE="class: cms_table_grid, width: 200"]
<tbody>[TR]
[TD][/TD]
[TD]3100[/TD]
[TD]3587[/TD]
[TD]3100[/TD]
[TD]3800[/TD]
[/TR]
[TR]
[TD]Talent[/TD]
[TD]200[/TD]
[TD]320[/TD]
[TD]124[/TD]
[TD]256[/TD]
[/TR]
[TR]
[TD]Sourcing[/TD]
[TD]90[/TD]
[TD]77[/TD]
[TD]85[/TD]
[TD]784[/TD]
[/TR]
[TR]
[TD]Media[/TD]
[TD]45[/TD]
[TD]69[/TD]
[TD]30[/TD]
[TD]941[/TD]
[/TR]
[TR]
[TD]Talent[/TD]
[TD]426[/TD]
[TD]25[/TD]
[TD]24[/TD]
[TD]4256[/TD]
[/TR]
[TR]
[TD]Sourcing[/TD]
[TD]497[/TD]
[TD]74[/TD]
[TD]85[/TD]
[TD]287[/TD]
[/TR]
[TR]
[TD]Media[/TD]
[TD]569[/TD]
[TD]36[/TD]
[TD]26[/TD]
[TD]365[/TD]
[/TR]
</tbody>[/TABLE]


In my 2nd worksheet the columns/rows are transposed but I need to be able to sum the total of all columns including combining col B & D (3100) for Sourcing etc. without the need to change/add anything to the datasheet. Eg the total for Sourcing/3100 = 757

[TABLE="class: cms_table_grid, width: 200"]
<tbody>[TR]
[TD][/TD]
[TD]Talent[/TD]
[TD]Sourcing[/TD]
[/TR]
[TR]
[TD]3100[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3587[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Any advise much appreciated.​
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
[TABLE="class: grid, width: 576"]
<tbody>[TR]
[TD="width: 64, bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent, align: right"]3100[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]3587[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]3100[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]3800[/TD]
[TD="width: 64, bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent"]Talent[/TD]
[TD="width: 64, bgcolor: transparent"]Sourcing[/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]Talent[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]200[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]320[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]124[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]256[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent, align: right"]3100[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]626[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]587[/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]Sourcing[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]90[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]77[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]85[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]784[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent, align: right"]3587[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]345[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]151[/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]Media[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]45[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]69[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]30[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]941[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]Talent[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]426[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]25[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]24[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]4256[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]Sourcing[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]497[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]74[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]85[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]287[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]Media[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]569[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]36[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]26[/TD]
[TD="width: 64, bgcolor: transparent, align: right"]365 [/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
</tbody>[/TABLE]

In H2 enter, copy across, and down:

=SUMIFS(INDEX($B$2:$E$7,0,MATCH($G2,$B$1:$E$1,0)),$A$2:$A$7,H$1)
 
Upvote 0
[TABLE="class: grid"]
<tbody>[TR]
[TD][/TD]
[TD]
A
[/TD]
[TD]
B
[/TD]
[TD]
C
[/TD]
[TD]
D
[/TD]
[TD]
E
[/TD]
[TD]
F
[/TD]
[TD]
G
[/TD]
[/TR]
[TR]
[TD]
1
[/TD]
[TD][/TD]
[TD]
3100​
[/TD]
[TD]
3587​
[/TD]
[TD]
3100​
[/TD]
[TD]
3800​
[/TD]
[TD][/TD]
[TD]sheet1[/TD]
[/TR]
[TR]
[TD]
2
[/TD]
[TD]Talent[/TD]
[TD]
200​
[/TD]
[TD]
320​
[/TD]
[TD]
124​
[/TD]
[TD]
256​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
3
[/TD]
[TD]Sourcing[/TD]
[TD]
90​
[/TD]
[TD]
77​
[/TD]
[TD]
85​
[/TD]
[TD]
784​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
4
[/TD]
[TD]Media[/TD]
[TD]
45​
[/TD]
[TD]
69​
[/TD]
[TD]
30​
[/TD]
[TD]
941​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
5
[/TD]
[TD]Talent[/TD]
[TD]
426​
[/TD]
[TD]
25​
[/TD]
[TD]
24​
[/TD]
[TD]
4256​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
6
[/TD]
[TD]Sourcing[/TD]
[TD]
497​
[/TD]
[TD]
74​
[/TD]
[TD]
85​
[/TD]
[TD]
287​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
7
[/TD]
[TD]Media[/TD]
[TD]
569​
[/TD]
[TD]
36​
[/TD]
[TD]
26​
[/TD]
[TD]
365​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


[TABLE="class: grid"]
<tbody>[TR]
[TD][/TD]
[TD]
A
[/TD]
[TD]
B
[/TD]
[TD]
C
[/TD]
[TD]
D
[/TD]
[TD]
E
[/TD]
[/TR]
[TR]
[TD]
1
[/TD]
[TD][/TD]
[TD]Talent[/TD]
[TD]Sourcing[/TD]
[TD][/TD]
[TD]sheet2[/TD]
[/TR]
[TR]
[TD]
2
[/TD]
[TD]
3100​
[/TD]
[TD]
774​
[/TD]
[TD]
757​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
3
[/TD]
[TD]
3587​
[/TD]
[TD]
345​
[/TD]
[TD]
151​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

sheet2

B2
=SUMPRODUCT((Sheet1!$B$1:$E$1=Sheet2!$A2)*(Sheet1!$A$2:$A$7=Sheet2!B$1)*(Sheet1!$B$2:$E$7)) copy down and across

 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,214
Messages
6,170,772
Members
452,353
Latest member
strainu

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