Forum Discussion
dsingh2255
Oct 19, 2022Brass Contributor
how to sort data with most occurance first with excel 2016 formula only
Hi All My data is like this:- User Sale Qty Amount Betty Beth 10 2000 Akshay Verma 20 1500 Ashley Adams 50 3500 Barney Beckham 25 6000 Beth Firch 35 7000 Akshay Ve...
- Oct 20, 2022
dsingh2255Here is the formula for 20,000 rows.
=IFNA(INDEX(A2:C20001,MATCH(ROW(1:20000),RANK(COUNTIF(A2:A20001,A2:A20001)+(1-(MATCH(A2:A20001,A2:A20001,0)/10^5))+(1-(ROW(A2:A20001)/10^10)),COUNTIF(A2:A20001,A2:A20001)+(1-(MATCH(A2:A20001,A2:A20001,0)/10^5))+(1-(ROW(A2:A20001)/10^10)),0),0),{1,2,3}),"")
I have added IFNA() so that you can prepare the formula whether the data is available or not. I think it is easy to understand. If you have more than 20k rows then you have to change the 20001 in the formula. If you have more than 99,999 rows you have to change the part 10^5 to 10^6 and the part 10^10 to 10^12. Good luck.
dsingh2255
Oct 19, 2022Brass Contributor
yes it does
dscheikey
Oct 19, 2022Bronze Contributor
- dsingh2255Oct 19, 2022Brass Contributorno brother,....i need same name should be together like both "Beth Finch" should be up down
- dscheikeyOct 19, 2022Bronze Contributor
So it took a bit, but now I have a formula that reproduces your order.
=INDEX(A2:C10,MATCH(ROW(1:9),RANK(COUNTIF(A2:A10,A2:A10)+(1-(MATCH(A2:A10,A2:A10,0)/100))+(1-(ROW(A2:A10)/10000)),COUNTIF(A2:A10,A2:A10)+(1-(MATCH(A2:A10,A2:A10,0)/100))+(1-(ROW(A2:A10)/10000)),0),0),{1,2,3})
If you have more than 100 rows that need to be sorted, the formula must be adjusted.
- dsingh2255Oct 19, 2022Brass Contributorcan you attach the excel file pls