Tough Winning Streak Formula

Autonomous

New Member
Joined
Apr 30, 2019
Messages
5
This is my first post on MrExcel and I really need a hand... I have a multi team game log where the dates are out of order and the data doesn't contain who played who so each team must be handled independently. I'm trying to figure out win streaks and current streaks "for each" team (Should I be writing VBA instead?) but my arrays aren't working properly. Any help would be appreciated!

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD="width: 103"][/TD]
[TD="width: 103, align: center"]A[/TD]
[TD="width: 103, align: center"]B[/TD]
[TD="width: 135, align: center"]C[/TD]
[TD="width: 148, align: center"]D[/TD]
[TD="width: 147, align: center"]E
[/TD]
[/TR]
[TR]
[TD="width: 103"]1[/TD]
[TD="width: 103"]3 Teams [/TD]
[TD="width: 103"]Date[/TD]
[TD="width: 135"]Result[/TD]
[TD="width: 148"]Max Win Streak[/TD]
[TD="width: 147"]Current Streak[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Red[/TD]
[TD="align: right"]1/20/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]Red[/TD]
[TD="align: right"]1/21/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]Red[/TD]
[TD="align: right"]4/20/2019[/TD]
[TD]Loss[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]Blue[/TD]
[TD="align: right"]1/10/2019[/TD]
[TD]Loss[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]Blue[/TD]
[TD="align: right"]1/2/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]Blue[/TD]
[TD="align: right"]1/4/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]Blue[/TD]
[TD="align: right"]1/9/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]Red[/TD]
[TD="align: right"]3/20/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]Red[/TD]
[TD="align: right"]1/6/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]Red[/TD]
[TD="align: right"]1/7/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]Green[/TD]
[TD="align: right"]1/15/2019[/TD]
[TD]Loss[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]13[/TD]
[TD]Red[/TD]
[TD="align: right"]1/22/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]14[/TD]
[TD]Green[/TD]
[TD="align: right"]2/13/2019[/TD]
[TD]Win[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]15[/TD]
[TD]Blue[/TD]
[TD="align: right"]1/3/2019[/TD]
[TD]Loss[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]16[/TD]
[TD]Green[/TD]
[TD="align: right"]1/14/2019[/TD]
[TD]Loss[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Welcome to Mr Excel Forum

Maybe something like this

[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][td="bgcolor: #DCE6F1"]
D
[/td][td="bgcolor: #DCE6F1"]
E
[/td][td="bgcolor: #DCE6F1"]
F
[/td][td="bgcolor: #DCE6F1"]
G
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
3 Teams​
[/td][td]
Date​
[/td][td]
Result​
[/td][td][/td][td]
Team​
[/td][td]
Max Win Streak​
[/td][td]
Current Streak​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Red​
[/td][td]
01/20/2019​
[/td][td]
Win​
[/td][td][/td][td]
Red​
[/td][td]
6​
[/td][td]
0​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Red​
[/td][td]
01/21/2019​
[/td][td]
Win​
[/td][td][/td][td]
Blue​
[/td][td]
2​
[/td][td]
0​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Red​
[/td][td]
04/20/2019​
[/td][td]
Loss​
[/td][td][/td][td]
Green​
[/td][td]
1​
[/td][td]
1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
Blue​
[/td][td]
01/10/2019​
[/td][td]
Loss​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
Blue​
[/td][td]
01/02/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
Blue​
[/td][td]
01/04/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td]
Blue​
[/td][td]
01/09/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
9
[/td][td]
Red​
[/td][td]
03/20/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
10
[/td][td]
Red​
[/td][td]
01/06/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
11
[/td][td]
Red​
[/td][td]
01/07/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
12
[/td][td]
Green​
[/td][td]
01/15/2019​
[/td][td]
Loss​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
13
[/td][td]
Red​
[/td][td]
01/22/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
14
[/td][td]
Green​
[/td][td]
02/13/2019​
[/td][td]
Win​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
15
[/td][td]
Blue​
[/td][td]
01/03/2019​
[/td][td]
Loss​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
16
[/td][td]
Green​
[/td][td]
01/14/2019​
[/td][td]
Loss​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
17
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Array formula in F2 copied down
=MAX(FREQUENCY(IF($A$2:$A$16=E2,IF(C$2:C$16="Win",B$2:B$16)),IF($A$2:$A$16=E2,IF(C$2:C$16="Loss",B$2:B$16))))
confirmed with Ctrl+Shift+Enter, not just Enter

Array formula in G2 copied down
=LOOKUP(9.99E+307,FREQUENCY(IF($A$2:$A$16=E2,IF(C$2:C$16="Win",B$2:B$16)),IF($A$2:$A$16=E2,IF(C$2:C$16="Loss",B$2:B$16))))
confirmed with Ctrl+Shift+Enter, not just Enter

Hope this helps

M.
 
Upvote 0
Welcome to Mr Excel Forum

Maybe something like this

[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[TD="bgcolor: #DCE6F1"]
D
[/TD]
[TD="bgcolor: #DCE6F1"]
E
[/TD]
[TD="bgcolor: #DCE6F1"]
F
[/TD]
[TD="bgcolor: #DCE6F1"]
G
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
3 Teams​
[/TD]
[TD]
Date​
[/TD]
[TD]
Result​
[/TD]
[TD][/TD]
[TD]
Team​
[/TD]
[TD]
Max Win Streak​
[/TD]
[TD]
Current Streak​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
Red​
[/TD]
[TD]
01/20/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD]
Red​
[/TD]
[TD]
6​
[/TD]
[TD]
0​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
Red​
[/TD]
[TD]
01/21/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD]
Blue​
[/TD]
[TD]
2​
[/TD]
[TD]
0​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
Red​
[/TD]
[TD]
04/20/2019​
[/TD]
[TD]
Loss​
[/TD]
[TD][/TD]
[TD]
Green​
[/TD]
[TD]
1​
[/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
Blue​
[/TD]
[TD]
01/10/2019​
[/TD]
[TD]
Loss​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
6
[/TD]
[TD]
Blue​
[/TD]
[TD]
01/02/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
7
[/TD]
[TD]
Blue​
[/TD]
[TD]
01/04/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
8
[/TD]
[TD]
Blue​
[/TD]
[TD]
01/09/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
9
[/TD]
[TD]
Red​
[/TD]
[TD]
03/20/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
10
[/TD]
[TD]
Red​
[/TD]
[TD]
01/06/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
11
[/TD]
[TD]
Red​
[/TD]
[TD]
01/07/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
12
[/TD]
[TD]
Green​
[/TD]
[TD]
01/15/2019​
[/TD]
[TD]
Loss​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
13
[/TD]
[TD]
Red​
[/TD]
[TD]
01/22/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
14
[/TD]
[TD]
Green​
[/TD]
[TD]
02/13/2019​
[/TD]
[TD]
Win​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
15
[/TD]
[TD]
Blue​
[/TD]
[TD]
01/03/2019​
[/TD]
[TD]
Loss​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
16
[/TD]
[TD]
Green​
[/TD]
[TD]
01/14/2019​
[/TD]
[TD]
Loss​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
17
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Array formula in F2 copied down
=MAX(FREQUENCY(IF($A$2:$A$16=E2,IF(C$2:C$16="Win",B$2:B$16)),IF($A$2:$A$16=E2,IF(C$2:C$16="Loss",B$2:B$16))))
confirmed with Ctrl+Shift+Enter, not just Enter

Array formula in G2 copied down
=LOOKUP(9.99E+307,FREQUENCY(IF($A$2:$A$16=E2,IF(C$2:C$16="Win",B$2:B$16)),IF($A$2:$A$16=E2,IF(C$2:C$16="Loss",B$2:B$16))))
confirmed with Ctrl+Shift+Enter, not just Enter

Hope this helps

M.


That did the trick! My problem was I forgot the $ symbols in my ranges thanks. I also converted everything to named ranges to make it tidy. Arrays can be pretty heavy with a larger data set any tips on better performance with arrays other than limiting the range to exact values and not the entire column?
 
Upvote 0
The most important thing is to limit the ranges - never use whole columns. But if the size of your data is huge the performance may not be good. Just testing to see ...

M.
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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