Find most common occurrence and display it.
Results 1 to 3 of 3

Thread: Find most common occurrence and display it.
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    New Member
    Join Date
    Oct 2014
    Posts
    8
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Find most common occurrence and display it.

    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

  2. #2
    MrExcel MVP Eric W's Avatar
    Join Date
    Aug 2015
    Location
    Bountiful, UT
    Posts
    8,475
    Post Thanks / Like
    Mentioned
    42 Post(s)
    Tagged
    5 Thread(s)

    Default Re: Find most common occurrence and display it.

    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.

    ABCDEFZAHAIANAQ
    1
    2Mon2Most CommonSpecificTextPantsMonxAlternateText
    3Tue3ShoesSpecificTextShirtsMonxAlternateText
    4Wed2SpecificTextPantsMonx
    5Thur1SpecificTextPantsTuexAlternateText
    6Fri3SpecificTextShoesTuexAlternateText
    7ShoesTuexAlternateText
    8BeltsxAlternateText
    9xSpecificTextShoesTuexAlternateText
    10SpecificTextShoesWedxAlternateText
    11SpecificTextShirtsWedAlternateText
    12SpecificTextShoesWedxAlternateText
    13SpecificTextPantsWedx
    14SpecificTextBeltsThurxAlternateText
    15SpecificTextPantsFriAlternateText
    16SpecificTextPantsFrixAlternateText
    17SpecificTextShirtsFrixAlternateText
    18PantsxAlternateText
    19SpecificTextShoesFrixAlternateText

    Data



    Array Formulas
    CellFormula
    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),"")))))))}
    Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
    Note: Do not try and enter the {} manually yourself



    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.
    Cheers,
    Eric

    When you eliminate the impossible, whatever remains, however improbable, must be the truth.

    -Posting guidelines, forum rules, terms of use, FAQs, BB codes, See how to search the forum
    -Post a screen shot with the HTML Maker

  3. #3
    New Member
    Join Date
    Oct 2014
    Posts
    8
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Find most common occurrence and display it.

    Thanks, Eric. I will play around with this over the next day or so and post back with real world data/progress.

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •