Looking to find most repeated text in a column on excel depending on criteria - 2 problems

SW82SW

New Member
Joined
Feb 10, 2025
Messages
12
Office Version
  1. 365
Platform
  1. Windows
I am part of a betting syndicate at work where we pick football teams to win their match every weekend. I keep a spreadsheet of the results and want to find the most picked team by each tipper and wondered if it was possible for it to show multiple answers in the same cell if there were multiple teams picked the same amount of times. If there was no team a tipper had picked multiple times then I would like it to show "all unique" or similar. I can get the most picked team but can't get it to show multiple teams or the "all unique" scenario.

I would also like to see the top 3 most successful picks and the 3 least successful picks for the group as a whole but I am not sure how to do this.

For my first problem, the most picked teams by tipster, (using Matthew as the example) I am using the following formula to return the most picked team. I am not sure how to return multiple answers in the same cell or show that all picks are unique:

=INDEX(Bets!$H11:$H108756,MODE(IF(Bets!$E11:$E108756="Matthew",IF(Bets!$H11:$H108756<>"",MATCH(Bets!$H11:$H108756,Bets!$H11:$H108756,{0,0})))))

For my second problem, the most and least successful teams picked by the group as a whole, I have used the following formula to return the most picked winning team and most picked losing team. "Y" is for a winning bet and "N" is for a losing bet:

=INDEX(Bets!$H11:$H108756,MODE(IF(Bets!$P11:$P108756="Y",IF(Bets!$H11:$H108756<>"",MATCH(Bets!$H11:$H108756,Bets!$H11:$H108756,{0,0})))))

=INDEX(Bets!$H11:$H108756,MODE(IF(Bets!$P11:$P108756="N",IF(Bets!$H11:$H108756<>"",MATCH(Bets!$H11:$H108756,Bets!$H11:$H108756,{0,0})))))

For all formulas column E is the tipper name, column H is the teams picked and column P is whether the pick won or not ("Y" or "N").

Thank you
 
A small sample of your data 15-20 rows and expected outcome would be helpful. You can share a snippet of your sheet using XL2BB.
 
Upvote 0
Welcome to the MrExcel board!

For my first problem ..
.. see if this is what you want.


SW82SW.xlsm
EH
10NameTeam
11Matthewa
12Johnd
13Annd
14Matthewb
15Matthewa
16Johnc
17Matthewb
18Matthewc
19Johnc
20Matthewf
21Matthewc
22Johna
23Matthewa
24Matthewc
25Matthewa
26Johnc
27Anne
28Matthewf
29Matthewf
30Matthewc
31Matthewf
Bets



Do you really need 100,000+ rows in the formula? I have used 1,000 but you can change that as required.

SW82SW.xlsm
AB
1NameMost
2Matthewa, c, f
3Jen 
4Johnc
5Annall unique
Sheet1
Cell Formulas
RangeFormula
B2:B5B2=LET(h,Bets!H$11:H$1000,e,Bets!E$11:E$1000,c,COUNTIFS(h,h,h,"<>",e,e),u,UNIQUE(SORT(FILTER(HSTACK(h,c),e=A2,{"",""}),2,-1)),tr,INDEX(u,1,2),IF(tr=1,"all unique",TEXTJOIN(", ",1,FILTER(TAKE(u,,1),TAKE(u,,-1)=tr))))
 
Upvote 0
Solution
An alternative means with Power Query

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"Name", "Team"}, {{"Count", each Table.RowCount(_), Int64.Type}}),
    #"Sorted Rows" = Table.Sort(#"Grouped Rows",{{"Name", Order.Descending}})
in
    #"Sorted Rows"
 
Upvote 0
=LET(h,Bets!H$11:H$1000,e,Bets!E$11:E$1000,c,COUNTIFS(h,h,h,"<>",e,e),u,UNIQUE(SORT(FILTER(HSTACK(h,c),e=A2,{"",""}),2,-1)),tr,INDEX(u,1,2),IF(tr=1,"all unique",TEXTJOIN(", ",1,FILTER(TAKE(u,,1),TAKE(u,,-1)=tr))))
@SW82SW do you have GROUPBY?
Peter's formula can be simplified using GROUPBY.
 
Upvote 0
Welcome to the MrExcel board!


.. see if this is what you want.


SW82SW.xlsm
EH
10NameTeam
11Matthewa
12Johnd
13Annd
14Matthewb
15Matthewa
16Johnc
17Matthewb
18Matthewc
19Johnc
20Matthewf
21Matthewc
22Johna
23Matthewa
24Matthewc
25Matthewa
26Johnc
27Anne
28Matthewf
29Matthewf
30Matthewc
31Matthewf
Bets



Do you really need 100,000+ rows in the formula? I have used 1,000 but you can change that as required.

SW82SW.xlsm
AB
1NameMost
2Matthewa, c, f
3Jen 
4Johnc
5Annall unique
Sheet1
Cell Formulas
RangeFormula
B2:B5B2=LET(h,Bets!H$11:H$1000,e,Bets!E$11:E$1000,c,COUNTIFS(h,h,h,"<>",e,e),u,UNIQUE(SORT(FILTER(HSTACK(h,c),e=A2,{"",""}),2,-1)),tr,INDEX(u,1,2),IF(tr=1,"all unique",TEXTJOIN(", ",1,FILTER(TAKE(u,,1),TAKE(u,,-1)=tr))))
This works great, thank you.

Would I be able to use a similar formula to find the 3 most picked teams that have won and the 3 most picked teams that have lost?
 
Upvote 0
Would I be able to use a similar formula to find the 3 most picked teams that have won and the 3 most picked teams that have lost?
As was requested in post #2, would really need to see a smallish sample of your data to see how it is presented and explain your expected results and reasoning in relation to that sample data.
If you have trouble with XL2BB, review the "XL2BB Icons greyed out" link in the 'Known XL2BB issues' section near the top of the linked Instructions page.
 
Upvote 0
This works great, thank you.

Would I be able to use a similar formula to find the 3 most picked teams that have won and the 3 most picked teams that have lost?

Never mind, I have managed to do it using your formula also but just changing the column I was looking up.

One other thing I would like to do is show the most commonly picked team by all tippers as a collective. How would I edit the formula to show this, again showing multiples if more than one team is most commonly picked? Using the example you posted above I would want to show that Team a was picked the most, but if Team a and Team b were both equally the most picked, then show both Team a and Team b in the same cell as my result.
 
Upvote 0
As was requested in post #2, would really need to see a smallish sample of your data to see how it is presented and explain your expected results and reasoning in relation to that sample data.
If you have trouble with XL2BB, review the "XL2BB Icons greyed out" link in the 'Known XL2BB issues' section near the top of the linked Instructions page.
Sorry Peter, I tried to use XL2BB but as I am using a work laptop it wouldn't allow me to use it.
 
Upvote 0

Forum statistics

Threads
1,226,771
Messages
6,192,924
Members
453,767
Latest member
922aloose

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