Countif or Sumif?

JTL9161

Active Member
Joined
Aug 29, 2012
Messages
471
Office Version
  1. 365
Platform
  1. Windows
I am trying to setup standings for my son's upcoming Fall/winter basketball league.

There will be 15 games (1 per week) with 6 teams (maybe more)

The wins/losses I can figure along with win percentage. What I am trying to add is a current streak for each team. I have each team listed (col A) with 15 cells to the right representing each week. Each week I will enter a W or L depending on their outcome. So now for example for Week 1 Team A wins and Team B loses. So Team A current streak is W-1 and Team B is L-1. Now for Week #2 lets say Team A wins again so I put a W in their next column and their streak is W-2. For Team B they also win so now their streak goes from L-1 to W-1. I will enter each weeks out come of W or L across for each week.

Is there a formula to put in column Q (col. A has team name and then col. B-P has weeks 1 - 15) that will read backwards from the most current week and count the number of same characters and put that character (W or L) and the number in secession? If a Team wins each other week then they will go from W-1 to L-1 back to W-1..etc. But if like Team A wins say their first 5 games after 5 weeks then there are 5 W's in their row giving them W-5.

Just trying to add some bells and whistles to the standings. I will also have points for and against, average points per game...etc.

Hope this is clear enough to understand
Thank you for your input.
James
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
81,518
Office Version
  1. 365
Platform
  1. Windows
For current win streak try
Excel Formula:
=COUNTIFS(XLOOKUP("L",B2:P2,B2:P2,B2,0,-1):P2,"W")
 
Upvote 0

JamesCanale

Well-known Member
Joined
Jan 13, 2021
Messages
854
Office Version
  1. 365
Platform
  1. Windows
MrExcelPlayground4.xlsx
ABCDEFGHIJKLMNOPQ
1Team111111111111111Streak
2AWWWWWW-5
3BWLLLL-3
4CLLWWWW-3
5DWLWLL-1
6ELWLLWW-1
7FLWLLWW-1
Sheet26
Cell Formulas
RangeFormula
Q2:Q7Q2=INDEX(FILTER(B2:P2,B2:P2<>""),1,COUNTA(FILTER(B2:P2,B2:P2<>"")))&"-"&IFNA(IF(INDEX(FILTER(B2:P2,B2:P2<>""),1,COUNTA(FILTER(B2:P2,B2:P2<>"")))="W",MATCH("L",INDEX(FILTER(B2:P2,B2:P2<>""),1,COUNTA(FILTER(B2:P2,B2:P2<>""))-SEQUENCE(1,COUNTA(FILTER(B2:P2,B2:P2<>"")))+1),0),MATCH("W",INDEX(FILTER(B2:P2,B2:P2<>""),1,COUNTA(FILTER(B2:P2,B2:P2<>""))-SEQUENCE(1,COUNTA(FILTER(B2:P2,B2:P2<>"")))+1),0))-1,COUNTA(FILTER(B2:P2,B2:P2<>"")))
 
Upvote 0

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
81,518
Office Version
  1. 365
Platform
  1. Windows
Another option, if you want a combined formula
Excel Formula:
=LET(WL,XLOOKUP("*",B2:P2,B2:P2,"",2,-1),WL&"-"&COUNTIFS(XLOOKUP(IF(WL="W","L","W"),B2:P2,B2:P2,B2,0,-1):P2,WL))
 
Upvote 0

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
12,597
Another approach:

Excel Formula:
=LOOKUP("Z",B2:P2)&"-"&ABS(MAX(COLUMN(B2:P2)*(B2:P2="W"),1)-MAX(COLUMN(B2:P2)*(B2:P2="L"),1))
 
Upvote 0

JTL9161

Active Member
Joined
Aug 29, 2012
Messages
471
Office Version
  1. 365
Platform
  1. Windows
Thank you ALL! Almost too many choices! Thanks again.
 
Upvote 0

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
81,518
Office Version
  1. 365
Platform
  1. Windows
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,186,365
Messages
5,957,443
Members
438,306
Latest member
Crystal_Blue

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
Top