SUM IF Dynamic range

LBTravis

New Member
Joined
Oct 1, 2015
Messages
8
[TABLE="width: 500"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Department[/TD]
[TD]Wages[/TD]
[TD]401K[/TD]
[/TR]
[TR]
[TD]Smith, John[/TD]
[TD]Admin[/TD]
[TD]10,000[/TD]
[TD]200[/TD]
[/TR]
[TR]
[TD]Lavine, Avril[/TD]
[TD]Sales[/TD]
[TD]500[/TD]
[TD]10[/TD]
[/TR]
[TR]
[TD]Turner, Ted[/TD]
[TD]Admin[/TD]
[TD]100[/TD]
[TD]10[/TD]
[/TR]
[TR]
[TD]Fonda, Jane[/TD]
[TD]Sales[/TD]
[TD]750[/TD]
[TD]75[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


I want to use an index match/sum if formula to sum the 401K column. The problem is that my data's columns maybe in a different order but the heading will always be the same. I know this is simple but I'm struggling.
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
You need to provide more information. What is the criteria that will determine whether something gets included in the sum? Is the goal to have a SUMIF with a dynamic criteria range, dynamic sum range, or both?
 
Upvote 0
The result should be:
Wages $11,350
401K $ 295

The goal is just to sum anything under the "401K" heading. And same thing to sum the entire "wages" column. The criteria will be the same but I can't use static cell references because these columns may be in different orders.
 
Upvote 0
Sorry for the delay in getting back to you on this. I've duplicated your table as follows:

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD][/TD]
[TD="align: center"]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[TD="align: center"]E[/TD]
[TD="align: center"]F[/TD]
[TD="align: center"]G[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD]Name[/TD]
[TD]Department[/TD]
[TD]Wages[/TD]
[TD]401k[/TD]
[TD][/TD]
[TD]Wages[/TD]
[TD]11350[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD]Smith, John[/TD]
[TD]Admin[/TD]
[TD]10,000[/TD]
[TD]200[/TD]
[TD][/TD]
[TD]401k[/TD]
[TD]295[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD]Lavine, Avril[/TD]
[TD]Sales[/TD]
[TD]500[/TD]
[TD]10[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD]Turner, Ted[/TD]
[TD]Admin[/TD]
[TD]100[/TD]
[TD]10[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD]Fonda, Jane[/TD]
[TD]Sales[/TD]
[TD]750[/TD]
[TD]75[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


In cell G2 I have the following formula:
Code:
=SUM(OFFSET($A$1,1,MATCH(F1,$A$1:$D$1,0)-1,COUNT($C:$C),1))

In cell G3 I have the following formula:
Code:
=SUM(OFFSET($A$1,1,MATCH(F2,$A$1:$D$1,0)-1,COUNT($C:$C),1))

The OFFSET function dynamically assigns the range to the SUM function. The MATCH statement inside the OFFSET determines what column to sum by matching what you're summing (Wages or 401k) to the column header.

The COUNT function allows your table to add rows and have those results included in the sum without having to modify the SUM formula.
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
Members
452,361
Latest member
d3ad3y3

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