SUMIF Problems (Special Case?)

sungersoo

New Member
Joined
Nov 9, 2017
Messages
34
Hello,

I am trying to run a sum of "Net Cash" to "Dupe Sum". The criteria are that if the client ID and time of day are the same, sum the net cash in to "Dupe Sum"...

Currently I am using this (=IF(AA2<>"",SUMIFS(AE:AE,F:F,F2,A:A,A2,AD:AD,AD2),"")) but it is also counting transactions that happens earlier or later in the day.

Is there any way for me to instead sum the current line and the lines after that show blanks.
i.e. Parks has a sale of 59.40 at 16:29 but show a total of 131.04 in "Dupe Sum" because it is totaling 59.4+35.88+23.88+11.88)

A B F AA AB AC AD AE
[TABLE="width: 792"]
<colgroup><col span="8"></colgroup><tbody>[TR]
[TD]UserName[/TD]
[TD]Purchase Date[/TD]
[TD]Client ID[/TD]
[TD]Dupe Check[/TD]
[TD]Dupe Sum[/TD]
[TD]BH Dupe[/TD]
[TD]Date[/TD]
[TD]Net Cash[/TD]
[/TR]
[TR]
[TD]Mark[/TD]
[TD]1/1/18 14:54[/TD]
[TD]122[/TD]
[TD]Mark[/TD]
[TD]14.88[/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]14.88[/TD]
[/TR]
[TR]
[TD]Shay[/TD]
[TD]1/1/18 16:08[/TD]
[TD]123[/TD]
[TD]Shay[/TD]
[TD]0[/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]Shay[/TD]
[TD]1/1/18 16:08[/TD]
[TD]123[/TD]
[TD] [/TD]
[TD] [/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]Parks[/TD]
[TD]1/1/18 16:29[/TD]
[TD]124[/TD]
[TD]Parks[/TD]
[TD]131.04[/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]59.4[/TD]
[/TR]
[TR]
[TD]Parks[/TD]
[TD]1/1/18 16:29[/TD]
[TD]124[/TD]
[TD] [/TD]
[TD] [/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]35.88[/TD]
[/TR]
[TR]
[TD]Parks[/TD]
[TD]1/1/18 16:29[/TD]
[TD]124[/TD]
[TD] [/TD]
[TD] [/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]23.88[/TD]
[/TR]
[TR]
[TD]Parks[/TD]
[TD]1/1/18 16:30[/TD]
[TD]124[/TD]
[TD] [/TD]
[TD] [/TD]
[TD]1[/TD]
[TD]1/1/2018[/TD]
[TD]11.88[/TD]
[/TR]
</tbody>[/TABLE]


Thank you so much in advance!
 
@jtakw

The breaks in column AA is something I was hoping I can work with.

Well, sort of, but the way you have your table setup makes it difficult to come up with a simpler formula, it should be a lot more efficient if we can use a Helper column, but this is what I have as it is:



Excel 2010
ABFAAABACADAE
1UserNamePurchase DateClient IDDupe CheckDupe SumBH DupeDateNet Cash
2Mark1/1/2018 14:54122Mark14.8811/1/201814.88
3Shay1/1/2018 16:08123Shay011/1/20180
4Shay1/1/2018 16:0812311/1/20180
5Parks1/1/2018 16:29124Parks131.0411/1/201859.4
6Parks1/1/2018 16:2912411/1/201835.88
7Parks1/1/2018 16:2912411/1/201823.88
8Parks1/1/2018 16:3012411/1/201811.88
9Parks1/1/2018 18:30124Parks99.9911/1/201899.99
10Parks1/1/2018 20:3012411/1/2018
11Parks1/1/2018 20:45124Parks999.9911/1/2018999.99
Sheet2
Cell Formulas
RangeFormula
AB2=IF(AA2<>"",SUMIFS(AE:AE,F:F,F2,A:A,A2,AD:AD,AD2)-SUMIFS(AE3:AE$2000,AA3:AA$2000,AA2,AD3:AD$2000,AD3)-SUMIFS(AB$1:AB1,AA$1:AA1,AA2,AD$1:AD1,AD1),"")


AB2 formula copied down.
 
Last edited:
Upvote 0

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes

Forum statistics

Threads
1,223,237
Messages
6,170,928
Members
452,366
Latest member
TePunaBloke

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