Autofilter using two date interval_dates stored in two columns

gyorid

New Member
Joined
Mar 8, 2018
Messages
2
Dear All,

I have a database of projects and I need to filter to those projects which were active in 2016.
Column J contains the projects' start date, column K contains the projects' end date in a mm/dd/yyyy format.
So I do not want my filtered list to contain projects that run out of this interval but I want to be able to list every single project that had at least 1 active day in 2016 based on the start date and end date information stored in two different columns.
The other columns contains information such as project tilte, amount, currency etc... (Columns from A to AE) but I guess this is irrelevant...

Is there a VBA code for this problem? I tried so many codes before but all of them were unable to carry out the filtering on a way I explained above.

Thank you very much in advance.

Best wishes,
Daniel Gyori
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
It's easy if you add a helper column (AF) which shows the number of days in 2016 between the start and end dates. In AF2 put the formula

=MAX(MIN(DATE(2016,12,31),K2)-MAX(DATE(2016,1,1),J2)+1,0)

and drag down to the last row. Then autofilter on column AF:
Code:
Public Sub Test()

    Dim lr As Long
    
    With ActiveSheet
        lr = .Cells(Rows.Count, "A").End(xlUp).Row
        .Range("A1:AF" & lr).AutoFilter Field:=32, Criteria1:=">0"
    End With

End Sub
 
Upvote 0
Thank you for this solution John_w!
This is a great help for me.
Have a great weekend!
Best,
Daniel
 
Upvote 0

Forum statistics

Threads
1,214,648
Messages
6,120,725
Members
448,987
Latest member
marion_davis

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