SUM IF with multiple column and row criteria

KATMUC

New Member
Joined
Dec 21, 2016
Messages
1

JanJanFebMarMarMar
Tax2227
Rent1117
Marketing3327
OPEX5517

<tbody>
</tbody>


JanFebMar
Tax
Rent
Marketing
OPEX

<tbody>
</tbody>

Hi, I was trying to summarise the various columns (I tagged several calendar weeks to Jan in a separate sheet), however
[FONT=Calibri, sans-serif]the formula =SUMIF($B$1:$F$5;J$2;INDEX($B$2:$F$5;0;MATCH($I3;$A$2:$A$5;0))) worked only for the first row (tax), and not for the remaining rows)[/FONT]
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result

AlanY

Well-known Member
Joined
Oct 30, 2014
Messages
4,342
Office Version
  1. 365
  2. 2019
  3. 2016
Platform
  1. Windows
try this


Excel 2012
ABCDEFG
1JanJanFebMarMarMar
2Tax2227
3Rent1117
4Marketing3327
5OPEX5517
6
7
8JanFebMar
9Tax427
10Rent217
11Marketing627
12OPEX1017
Sheet4
Cell Formulas
RangeFormula
B9=SUMIFS(INDEX($B$1:$G$5,MATCH($A9,$A$1:$A$5,0),0),INDEX($B$1:$G$5,1,0),B$8)
 

MARZIOTULLIO

Well-known Member
Joined
Aug 22, 2015
Messages
767
A
B
C
D
E
F
G
1
JanJanFebMarMarMar
2
Tax
2​
2​
2​
7​
3
Rent
1​
1​
1​
7​
4
Marketing
3​
3​
2​
7​
5
OPEX
5​
5​
1​
7​
6
7
8
JanFebMar
9
Tax
4​
2​
7​
10
Rent
2​
1​
7​
11
Marketing
6​
2​
7​
12
OPEX
10​
1​
7​

<tbody>
</tbody>


b9=SUMPRODUCT(($A$2:$A$5=$A9)*($B$1:$G$1=B$8)*($B$2:$G$5)) copy across and down
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,626
Messages
5,838,430
Members
430,547
Latest member
jopshio

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
Top