Finding Current AND Longest Winning Streak based on TWO Criteria

SnKeaK

New Member
Joined
Oct 27, 2012
Messages
32
Office Version
  1. 365
Platform
  1. Windows
[TABLE="width: 363"]
<tbody>[TR]
[TD="colspan: 2"]Status[/TD]
[TD]Bookmaker[/TD]
[TD]Rating[/TD]
[/TR]
[TR]
[TD="colspan: 2"]Win[/TD]
[TD]Nitrogen Sports[/TD]
[TD]Pick of the Day[/TD]
[/TR]
[TR]
[TD="colspan: 2"]Loss[/TD]
[TD]Nitrogen Sports[/TD]
[TD]Regular[/TD]
[/TR]
[TR]
[TD="colspan: 2"]Win[/TD]
[TD]TRP Special[/TD]
[TD]Pick of the Day[/TD]
[/TR]
[TR]
[TD="colspan: 2"]Loss[/TD]
[TD]TRP Special[/TD]
[TD]Pick of the Night[/TD]
[/TR]
[TR]
[TD="colspan: 2"]Win[/TD]
[TD]TRP Special[/TD]
[TD]Pick of the Day[/TD]
[/TR]
[TR]
[TD="colspan: 2"]Win[/TD]
[TD]TRP Special[/TD]
[TD]Pick of the Night[/TD]
[/TR]
</tbody>[/TABLE]

Alright, So I am trying to find the current Win Streak for "Pick of the Day". n this example it'd be 3 because Column A = Win AND Column C = Pick of the Day. However if you look for the current streak of Pick of the Night, it'd only be 1. I need formula to find Current and another formula to find Longest streak given two criteria...Criteria being Column A = Win and Column C = Pick of the Day(for this example)

I figure I'd have to use MAX and Frequency combo but I can't figure out how to incorporate them based on if two criteria are met. Thanks.
 
I'm afraid i misunderstood what you are looking for. Does the current streak begin in A1?

M.
 
Upvote 0

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Base on your example yes. For Pick of the Day the Current Streak begins A1, because it hasn't lost. For Pick of the Night, it'd be A13. Now let's say we change A11 to Win...The Pick of the Night Current streak would have started on A8 and the current streak would be 5
 
Last edited:
Upvote 0
See if this is ok

[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]
[TD="bgcolor: #DCE6F1"]
H
[/TD]
[TD="bgcolor: #DCE6F1"]
I
[/TD]
[TD="bgcolor: #DCE6F1"]
J
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
Win​
[/TD]
[TD]
Nitrogen Sports​
[/TD]
[TD]
Pick of the Day​
[/TD]
[TD][/TD]
[TD]
Criteria1​
[/TD]
[TD]
Criteria2​
[/TD]
[TD]
Max Streak​
[/TD]
[TD]
DataLastRow​
[/TD]
[TD]
LastRow<>Criteria​
[/TD]
[TD]
Current Streak​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
Loss​
[/TD]
[TD]
Nitrogen Sports​
[/TD]
[TD]
Regular​
[/TD]
[TD][/TD]
[TD]
Win​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD]
3​
[/TD]
[TD]
13​
[/TD]
[TD]
11​
[/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Day​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
Loss​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Day​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
6
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
7
[/TD]
[TD]
Loss​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
8
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
9
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
10
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
11
[/TD]
[TD]
Loss​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
12
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Day​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
13
[/TD]
[TD]
Win​
[/TD]
[TD]
TRP Special​
[/TD]
[TD]
Pick of the Night​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
14
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Criteria in E2:F2

Max streak
Array formula in G2
=MAX(FREQUENCY(IF(C1:C100=F2,IF(A1:A100=E2,ROW(A1:A100))),IF(C1:C100=F2,IF(A1:A100<>E2,ROW(A1:A100)))))
Ctrl+Shift+Enter

Formula in H2 (last row with data)
=MATCH(REPT("z",255),B:B)

Formula in I2 (last row: column C=F2 and column A=Loss)
=IFERROR(LOOKUP(2,1/((C1:C100=F2)*(A1:A100<>E2)*(A1:A100<>"")),ROW(B1:B100)),1)

Current streak
=COUNTIFS(INDEX(A:A,H2):INDEX(A:A,I2),E2,INDEX(C:C,H2):INDEX(C:C,I2),F2)

M.
 
Upvote 0
That did it! Thank you so much. I really appreciate your time on this.
 
Upvote 0

Forum statistics

Threads
1,223,908
Messages
6,175,307
Members
452,633
Latest member
DougMo

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