sum data between two cell values

slamanager

Board Regular
Joined
Apr 20, 2007
Messages
129
Hi All,

I know this is a question like using Sumproduct to total data between dates but i just cant get this to work.

Each line in the report shows a status change with in a record there are multiple records in the report, also there are random combinations of status changes per record. Im trying to sum the minutes in duration between two of the status types.

example data in cols A B C. A is the record ID B is the Status value and C is the duration for each status.
INC0001, Start, 15
INC0001, Process1, 5
INC0001, Process2, 11
INC0001, Process4, 6
INC0001, Process1, 5
INC0001, End, 7
INC0001, Refresh, 5
INC0002, Start, 15
INC0002, Process1, 5
INC0002, Process2, 14
INC0002, Process1, 5
INC0002, End, 7

So I need to calc the duration for INC0001 between Start and End points giving a total of 49 and INC0002 total of 46. the sumproduct example i have is for date ranges which ive tried to modify by unsure how to combine the INC ref and the status and then add up between those points.

Cheers
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
IDStatusDuration INC0001
INC0001Start15 Start
INC0001Process15 End
INC0001Process211 49
INC0001Process46
INC0001Process15
INC0001End7
INC0001Refresh5
INC0002Start15
INC0002Process15
INC0002Process214
INC0002Process15
INC0002End7

<COLGROUP><COL style="WIDTH: 48pt" span=3 width=64><COL style="WIDTH: 20pt; mso-width-source: userset; mso-width-alt: 967" width=27><COL style="WIDTH: 18pt; mso-width-source: userset; mso-width-alt: 853" width=24><COL style="WIDTH: 48pt" width=64><TBODY>
</TBODY>

Not sure if this is possible/easy with a pivot table. What follows is a formula approach...

F4, control+shift+enter, not just enter:
Rich (BB code):
=SUM(
  IF(ROW($B$2:$B$13)-ROW(B$2)+1>=MATCH(F2,IF($A$2:$A$13=F1,$B$2:$B$13),0),
  IF(ROW($B$2:$B$13)-ROW(B$2)+1<=MATCH(F3,IF($A$2:$A$13=F1,$B$2:$B$13),0),
  IF($A$2:$A$13=F1,$C$2:$C$13))))
 
Upvote 0

Forum statistics

Threads
1,213,510
Messages
6,114,048
Members
448,543
Latest member
MartinLarkin

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