In this article I will show you how to extract the most frequent value (text or number) between two dates in a column.

Most common value between two dates in excel

Array formula in C17:

=INDEX(Values_col, MATCH(MAX(FREQUENCY(IF((Dates_col<=$B$15)*(Dates_col>=$B$14), COUNTIF(Values_col, "<"&Values_col), ""), COUNTIF(Values_col, "<"&Values_col))), FREQUENCY(IF((Dates_col<=$B$15)*(Dates_col>=$B$14), COUNTIF(Values_col, "<"&Values_col), ""), COUNTIF(Values_col, "<"&Values_col)), 0)) + CTRL + SHIFT + ENTER

How to create an array formula

  1. Copy array formula
  2. Select cell C17
  3. Click in formula bar
  4. Paste (Ctrl + v)
  5. Press and hold CTRL + SHIFT
  6. Press ENTER

Named ranges

Date_col (B2:B11)
Values_col (A2:A11)

What is named ranges?

Download excel file for this tutorial.

Most common value between two dates.xls
(Excel 97-2003 Workbook *.xls)

Functions in this article:

MATCH(lookup_value;lookup_array; [match_type]
Returns the relative position of an item in an array that matches a specified value

INDEX(array,row_num,[column_num])
Returns a value or reference of the cell at the intersection of a particular row and column, in a given range

ROW(reference) returns the rownumber of a reference

IF(logical_test;[value_if:true];[value_if_false])
Checks whether a condition is met, and returns one value if TRUE, and another value if FALSE

MAX(number1,[number2],)
Returns the largest value in a set of values. Ignores logical values and text.

COUNTIF(range,criteria)
Counts the number of cells within a range that meet the given condition

FREQUENCY(data_array, bins_array)
Calculates how often values occur within a range of values and then returns a vertical array of numbers having one more element than Bins_array.

Related articles: