Sumif Function within Subtotal

mcbiz77

New Member
Joined
Feb 9, 2016
Messages
17
I'm looking for a subtotal equation that I can use that sums a total column when filtered based on a criteria (sumif) for tbd. I'm currently using the following equation........=sumif($A:$A,"tbd*",B:B). The table below shows what I have when a filter is in place. Three names pop up when the filter is in place, however I need to find the total for tbd. What subtotal equation can I use to find the total for tbd when a filter is in place? The output should be tbd=1.

NameTotal
John
1
tbd1
Rick1

<tbody>
</tbody>
 

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
Yes that formula =SUMIF(A2:A5,"="&"<acronym title="To be discussed" style="border-width: 0px 0px 1px; border-bottom-style: dotted; border-bottom-color: rgb(0, 0, 0); cursor: help; color: rgb(51, 51, 51); background-color: rgb(250, 250, 250);">tbd</acronym>",B2:B5) does work however when a filter has been applied to the spreadsheet it shows all the tbd within the entire spreadsheet and not just the tbd within the filter. I'm looking for a formula that performs the same way as a =SUBTOTAL(109...... command.
 
Upvote 0
Use a helper column for the subtotal.

Say C2
=SUBTOTAL(103,A2)
And fill down to C5

Then use
=SUMIFS(B2:B5,A2:A5,"tbd",C2:C5,1)
 
Upvote 0
ABC
1LevelNameQty
2A
John1
3AAmy1
4BDave1
5AJohn2
6BDave2
7AAmy1
8BJohn2
9
10Total=subtotal(109,C2:C8)10
John=sumif(B2:B8,"John",C2:C8)5

<tbody>
</tbody>



















The formula doesn't seem to be working. The table above is what i'm working with. The total comes out to 10 which is correct. The sum for John (5) is correct too. However, if I was to put a filter on column A and filter only by Level B then I would like my total for John to only sum the Qty under that filter. For example, if I was to filter by level B then my Total changes from 10 to 5 which it does with teh subtotal formula however the total for John will need to go from 5 to 2. Do you know what formula I could use instead of =sumif(B2:B8,"John",C2:C8)?
 
Upvote 0
That's not exactly what I suggested


Unknown
ABCDEF
1LevalNameQtySubtotal5
2AJohn11
3AAmy11
4BDave11
5AJohn21
6BDave21
7AAmy11
8BJohn21
Sheet1
Cell Formulas
RangeFormula
F1=SUMIFS(C2:C8,B2:B8,"John",D2:D8,1)
D2=SUBTOTAL(103,A2)
D3=SUBTOTAL(103,A3)
D4=SUBTOTAL(103,A4)
D5=SUBTOTAL(103,A5)
D6=SUBTOTAL(103,A6)
D7=SUBTOTAL(103,A7)
D8=SUBTOTAL(103,A8)
 
Upvote 0
Try...

=SUMPRODUCT(SUBTOTAL(109,OFFSET(C2,ROW(C2:C8)-ROW(C2),0,1),(B2:B8="John")+0)

Note. Function number 9 instead of 109 might also work as intended.
 
Upvote 0
After adding the formulas as shown above, i'm having problems with the filter. When filtering for Level A within column A, I get all the Level A but I also get a Level B which I shouldn't. It seems like the formulas in column D are messing up the filters.
 
Upvote 0
Is that data in an actual TABLE ?

This is an actual bug in Excel, that the presense of a subtotal function in a Table makes that Table think there is a totals row. That makes the last row ignored.

Try changing the formula in D2 to
=SUM(SUBTOTAL(103,A2))

Or if you have XL2010+
=AGGREGATE(3,1,A2)
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,743
Messages
6,126,605
Members
449,321
Latest member
syzer

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