Results 1 to 4 of 4

Thread: Formula To Show The Most Common Or Frequent Day For An Entry

  1. #1
    Junior Member
    Join Date
    Apr 2014
    Posts
    2
    Rep Power
    0

    Formula To Show The Most Common Or Frequent Day For An Entry

    Just new to this and have a query!

    I have a list of people with corresponding dates and I want excel to take the DAY from the date and show me what day is most common day for each person. I.e if a person is against 14-Jul-2014; 14-Aug-2014 and 15-Sep-2014 the cell would show 14th as the most common date for that person. I have been looking at MODE; COUNTIF; SUMIF and DAY commands along with date formats/suffix but haven't cracked it as yet.

    Problem.jpg

  2. #2
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    Use this as an array formula

    =IFERROR("Day "&MODE(IF($B$2:$B$36=D2,DAY($A$2:$A$36),""))," All are unique")

    Sample attached
    Attached Files Attached Files
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

  3. #3
    Junior Member
    Join Date
    Apr 2014
    Posts
    2
    Rep Power
    0
    Excellent this appears to be working for me! Just one question however, is there a way to remove "Day " and replace with the date suffix instead? E.g 01st; 04th; 11th; 13th instead of Day 1; Day 4; Day 11; Day 13th?

    I did notice this from previously

    Ordinal Suffix (i.e., "st", "nd", "rd" and "th")
    Here is an Excel function that can be used in a cell formula to apply the proper ordinal suffix to the number specified (in cell A1 for this example)...

    MID("thstndrdth",MIN(9,2*RIGHT(A1)*(MOD(A1-11,100)>2)+1),2)

    More than likely, you will use this function within an Excel formula by concatenating it after the number that is specified with in the function. For example, if cell B1 contains the number, then your formula could be something like this...

    ="Ordinal for B1: "&B1&MID("thstndrdth",MIN(9,2*RIGHT(B1)*(MOD(B 1-11,100)>2)+1),2)
    - just not sure about incorperating it into the previous formula!

  4. #4
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    Try this in E2 as array formula, and drag down

    =IFERROR(MODE(IF($B$2:$B$36=D2,DAY($A$2:$A$36),"") )&MID("thstndrdth",MIN(9,2*RIGHT(MODE(IF($B$2:$B$3 6=D2,DAY($A$2:$A$36),"")))*(MOD(MODE(IF($B$2:$B$36 =D2,DAY($A$2:$A$36),""))-11,100)>2)+1),2),"All are unique")
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

Similar Threads

  1. A code to show colour in cell from list
    By rodneykaye in forum Excel Help
    Replies: 4
    Last Post: 10-18-2013, 03:56 PM
  2. Nth Day Of Week Number Using Formula
    By paul_pearson in forum Excel Help
    Replies: 2
    Last Post: 06-16-2013, 06:40 PM
  3. Date Format From Start Day To End Day
    By PcMax in forum Excel Help
    Replies: 2
    Last Post: 03-10-2013, 02:07 PM
  4. VBA Show Message On Sheet Activate
    By Howardc in forum Excel Help
    Replies: 2
    Last Post: 10-29-2012, 08:17 PM
  5. List Unique/Common Values From Two Ranges
    By Admin in forum Excel and VBA Tips and Tricks
    Replies: 0
    Last Post: 09-16-2011, 08:34 AM

Posting Permissions

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