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
 

Some videos you may like

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.

John_w

MrExcel MVP
Joined
Oct 15, 2007
Messages
6,323
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
 

gyorid

New Member
Joined
Mar 8, 2018
Messages
2
Thank you for this solution John_w!
This is a great help for me.
Have a great weekend!
Best,
Daniel
 

Watch MrExcel Video

Forum statistics

Threads
1,102,574
Messages
5,487,644
Members
407,607
Latest member
obletihucp

This Week's Hot Topics

  • Timer in VBA - Stop, Start, Pause and Reset
    [CODE=vba][/CODE] Option Explicit Dim CmdStop As Boolean Dim Paused As Boolean Dim Start Dim TimerValue As Date Dim pausedTime As Date Sub...
  • how to updates multiple rows in muliselect listbox
    Hello everyone. I need help with below code. code is only chaning 1st row in mulitiselect list box. i know issue with code...
  • Delete Row from Table
    I am trying to delete a row from a table using VBA using a named range to find what I need to delete. My Range is finding the right cell. In the...
  • Assigning to a variable
    I have a for each block where I want to assign the value in column 5 of the found row to the variable Serv. [CODE=vba] For Each ws In...
  • Way to verify information
    Hi All, I don't know what to call this formula, and therefore can't search. I have a spreadsheet with information I want to reference...
  • Active Cell Address – Inactive Sheet
    How to use VBA to get the cell address of the active cell in an inactive worksheet and then place that cell address in a location on the current...
Top