Sumifs? Variable input criteria to set sum column for sum?

dwarnimont

Board Regular
Joined
Jan 12, 2010
Messages
71
What is formula, sumifs, indirect, other, to sum based on multiple input criteria (similar to vloookup + hvoolup) where it sums data in one column, based on input to select this column from with range of data.
Example objective. Sum all that meet input criterias. Input=SKU, range is Col A. Input=year, range is row #1 . for example if it is SKU B and year 2019, goto sum range and return the sum.
This is very close to sumifs, yet it is not fixed on a specific column and must select the column to sum based on input criteria.

A B C D E
1SKU2018201920202021
2A11,75135,38273,246126,215
3B10,00929,68759,580101,894
4C9,89029,50959,580101,894
5A9,64829,24159,580101,894
6A41,298123,819251,986431,897
7C4,5738,34022,38260,470
8C4,0867,04316,62744,534
9B4,1147,09716,62744,534
10A4,0817,05716,62744,534
11A16,85429,53772,263194,072
12
13 Input (formula)
14SKUB
15Year2019
16
17Formula answer-->36,784

<colgroup><col><col><col span="4"></colgroup><tbody>
</tbody>
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
A
B
C
D
E
1
SKU
2018​
2019​
2020​
2021​
2
A
11,751​
35,382​
73,246​
126,215​
3
B
10,009​
29,687​
59,580​
101,894​
4
C
9,890​
29,509​
59,580​
101,894​
5
A
9,648​
29,241​
59,580​
101,894​
6
A
41,298​
123,819​
251,986​
431,897​
7
C
4,573​
8,340​
22,382​
60,470​
8
C
4,086​
7,043​
16,627​
44,534​
9
B
4,114​
7,097​
16,627​
44,534​
10
A
4,081​
7,057​
16,627​
44,534​
11
A
16,854​
29,537​
72,263​
194,072​
12
13
14
SKUB
15
Year
2019​
16
17
36784​

<tbody>
</tbody>

B17=SUMPRODUCT(($A$2:$A$11=B14)*($B$1:$E$1=B15)*($B$2:$E$11))
 
Upvote 0
Yes, this is it. Very appreciative. I know how to do this years ago, and I save all my formulas, but my brain faded on this one. Thanks!!!!!!!!!
 
Upvote 0
=SUMIFS(INDEX($B$2:$E$11,0,MATCH(B15,$B$1:$E$1,0)),$A$2:$A$11,B14)

which is faster and more appropriate for the task.
 
Upvote 0

Forum statistics

Threads
1,215,731
Messages
6,126,537
Members
449,316
Latest member
sravya

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