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]
 

Some videos you may like

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.

AlanY

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

<b>Excel 2012</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style=";">Jan</td><td style=";">Jan</td><td style=";">Feb</td><td style=";">Mar</td><td style=";">Mar</td><td style=";">Mar</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Tax</td><td style="text-align: right;;">2</td><td style="text-align: right;;">2</td><td style="text-align: right;;">2</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Rent</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Marketing</td><td style="text-align: right;;">3</td><td style="text-align: right;;">3</td><td style="text-align: right;;">2</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">OPEX</td><td style="text-align: right;;">5</td><td style="text-align: right;;">5</td><td style="text-align: right;;">1</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</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><td style="text-align: right;;"></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><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=";">Jan</td><td style=";">Feb</td><td style=";">Mar</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=";">Tax</td><td style="text-align: right;background-color: #E2EFDA;;">4</td><td style="text-align: right;background-color: #E2EFDA;;">2</td><td style="text-align: right;background-color: #E2EFDA;;">7</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;">10</td><td style=";">Rent</td><td style="text-align: right;background-color: #E2EFDA;;">2</td><td style="text-align: right;background-color: #E2EFDA;;">1</td><td style="text-align: right;background-color: #E2EFDA;;">7</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;">11</td><td style=";">Marketing</td><td style="text-align: right;background-color: #E2EFDA;;">6</td><td style="text-align: right;background-color: #E2EFDA;;">2</td><td style="text-align: right;background-color: #E2EFDA;;">7</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;">12</td><td style=";">OPEX</td><td style="text-align: right;background-color: #E2EFDA;;">10</td><td style="text-align: right;background-color: #E2EFDA;;">1</td><td style="text-align: right;background-color: #E2EFDA;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet4</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">B9</th><td style="text-align:left">=SUMIFS(<font color="Blue">INDEX(<font color="Red">$B$1:$G$5,MATCH(<font color="Green">$A9,$A$1:$A$5,0</font>),0</font>),INDEX(<font color="Red">$B$1:$G$5,1,0</font>),B$8</font>)</td></tr></tbody></table></td></tr></table><br />
 

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
 

Watch MrExcel Video

Forum statistics

Threads
1,128,053
Messages
5,628,325
Members
416,311
Latest member
S991102

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