finding the most repeated dates in a range

redahussien

New Member
Joined
Feb 15, 2016
Messages
3
hi all,
can you help in finding the most repeated dates in a range a1:d4

ABCD
2/2/2009

<tbody>
</tbody>
2/2/2009

<tbody>
</tbody>
2/2/2009

<tbody>
</tbody>
2/2/2010

<tbody>
</tbody>
4/21/2009

<tbody>
</tbody>
2/1/2009

<tbody>
</tbody>
8/8/2009

<tbody>
</tbody>
2/12/2009

<tbody>
</tbody>
2/2/2009

<tbody>
</tbody>
2/2/2009

<tbody>
</tbody>
4/21/2009

<tbody>
</tbody>
2/12/2009

<tbody>
</tbody>
8/8/2009

<tbody>
</tbody>
2/12/2009

<tbody>
</tbody>
2/2/2009

<tbody>
</tbody>
2/2/2009

<tbody>
</tbody>

<tbody>
</tbody>

i want to list all the repeated values from the most to the least :

dates repeated
2/2/2009 7
2/12/2009 3
2/2/2009 3
4/21/2009 2
8/8/2009 2
2/1/2009 1
2/2/2010 1

note that the columns dates and repeated are formula generated , i want to extract them and count the repetition. cos i have a large list of dates.
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Here is one way, using VBA
- run from sheet containing dates

Code:
Sub CountDates()
    Dim cel As Range, rng As Range, ws As Worksheet, r As Long
    Set rng = ActiveSheet.Range("A1").CurrentRegion              '[COLOR=#006400]amend range if necessary to match your data[/COLOR]
    
    Set ws = Worksheets.Add
    For Each cel In rng
        r = r + 1
        ws.Cells(r, 1).Resize(, 2) = Array(cel, WorksheetFunction.CountIf(rng, cel))
    Next cel
    With ws.Range("A:B")
        .RemoveDuplicates Columns:=Array(1, 2), Header:=xlNo
        .Sort Key1:=Range("B1"), Order1:=xlDescending, Header:=xlNo
        .Resize(, 1).NumberFormat = rng.Cells(1, 1).NumberFormat
    End With
End Sub


Sheet with dates starting in A1

Excel 2016 (Windows) 32 bit
A
B
C
D
1
29/08/2019​
29/08/2019​
30/08/2019​
31/08/2019​
2
01/09/2019​
28/08/2019​
27/08/2019​
01/09/2019​
3
04/09/2019​
01/09/2019​
29/08/2019​
28/08/2019​
4
02/09/2019​
29/08/2019​
01/09/2019​
27/08/2019​
5
02/09/2019​
27/08/2019​
28/08/2019​
29/08/2019​
6
01/09/2019​
30/08/2019​
01/09/2019​
01/09/2019​
7
04/09/2019​
31/08/2019​
31/08/2019​
05/09/2019​
8
31/08/2019​
29/08/2019​
05/09/2019​
03/09/2019​
9
27/08/2019​
03/09/2019​
27/08/2019​
04/09/2019​
10
28/08/2019​
27/08/2019​
05/09/2019​
03/09/2019​
11
03/09/2019​
01/09/2019​
29/08/2019​
28/08/2019​
12
30/08/2019​
31/08/2019​
27/08/2019​
03/09/2019​
13
05/09/2019​
30/08/2019​
02/09/2019​
30/08/2019​
14
29/08/2019​
02/09/2019​
30/08/2019​
03/09/2019​
Sheet: Sheet12

Output in new sheet (from most to least)

Excel 2016 (Windows) 32 bit
A
B
1
29/08/2019​
8​
2
01/09/2019​
8​
3
27/08/2019​
7​
4
30/08/2019​
6​
5
03/09/2019​
6​
6
31/08/2019​
5​
7
28/08/2019​
5​
8
02/09/2019​
4​
9
05/09/2019​
4​
10
04/09/2019​
3​
Sheet: Sheet19
 
Upvote 0
it works perfect Man , thanks a Million.
ill try to modify it to get the top 5 , if it does not work with me ill get back to you.
thanks in advance.
 
Upvote 0
If you simply want to be left with the first 5 values, then add this as the last line

Code:
ws.Range("A6").Resize(Rows.Count - 5).EntireRow.Delete
 
Upvote 0

Forum statistics

Threads
1,213,504
Messages
6,114,020
Members
448,543
Latest member
MartinLarkin

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