Find most common occurrence and display it.

dad2sdt

New Member
Joined
Oct 24, 2014
Messages
8
Hi Community,

Been trying to figure this out all morning. I have a range of data, with column headers. I have computed values based on certain criteria in a range of cells Similar to the following: Lets call it clothing items.

Mon 400
Tue 300
Wed 6
Thur 7
Fri 50

I have computed this with the following formula: =COUNTIFS(Data!AN:AN,B9,Data!AI:AI,"Mon",Data!Z:Z,"SpecificText",Data!AQ:AQ,"AlternateText") replacing Tue, Wed...for Mon on each row. With this, I can see that I have sold 400 items on Monday, 300 on Tuesday...

Now out of those values, I want to display the most common occurrence of what made up that 763 items. I was trying to, unsuccessfully with the following formula based on some searches but I cannot figure it out. The goal is for Cell E26 to display the word Shirts, Pants, Shoes, based on if that is the most common thing sold that week. The item sold is in column AH of which I am trying to figure out which was sold most.

Cell E26: =INDEX(Data!AH:AH, 10000*MOD(MAX(COUNTIF(Data!AH2:AH1000000,Data!AH2:AH1000000)+(ROW(Data!AH2:AH1000000)/10000)),1), 1)

Any ideas welcomed.

Jeff

Jeff
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
It would have been helpful if you could have displayed an example of your sheets. Nevertheless, I tried to create a small sample derived from your formulas.


Book1
ABCDEFZAHAIANAQ
1
2Mon2Most CommonSpecificTextPantsMonxAlternateText
3Tue3ShoesSpecificTextShirtsMonxAlternateText
4Wed2SpecificTextPantsMonx
5Thur1SpecificTextPantsTuexAlternateText
6Fri3SpecificTextShoesTuexAlternateText
7ShoesTuexAlternateText
8BeltsxAlternateText
9xSpecificTextShoesTuexAlternateText
10SpecificTextShoesWedxAlternateText
11SpecificTextShirtsWedAlternateText
12SpecificTextShoesWedxAlternateText
13SpecificTextPantsWedx
14SpecificTextBeltsThurxAlternateText
15SpecificTextPantsFriAlternateText
16SpecificTextPantsFrixAlternateText
17SpecificTextShirtsFrixAlternateText
18PantsxAlternateText
19SpecificTextShoesFrixAlternateText
Data
Cell Formulas
RangeFormula
D3{=INDEX(Data!$AH$2:$AH$1000,MODE(IF(ISNUMBER(MATCH(Data!$AI$2:$AI$1000,{"Mon","Tue","Wed","Thur","Fri"},0)),IF($Z$2:$Z$1000="SpecificText",IF($AQ$2:$AQ$1000="AlternateText",IF($AN$2:$AN$1000=B9,IFERROR(MATCH($AH$2:$AH$1000,$AH$2:$AH$1000,0),"")))))))}
Press CTRL+SHIFT+ENTER to enter array formulas.


If this is close, then you can use the D3 formula to find the most common item type. You'll need to adjust the formula for your sheets.
 
Upvote 0
Thanks, Eric. I will play around with this over the next day or so and post back with real world data/progress.
 
Upvote 0

Forum statistics

Threads
1,213,560
Messages
6,114,309
Members
448,564
Latest member
ED38

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