Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Return nearest Date value from another table, filtering

Hello!

 

I have a table 'A' with [ID]; [Name]; [Start Date Planned] and [Finish Date Planned]

 

And a table 'B' with [ID]; [Name]; [Start Date Acomplished] and [Finish Date Acomplished]

 

In the table 'A' I must create a new column matching [ID] and [Name] from table 'B' and returning the nearest [Start Date Acomplished] and the nearest [Finishi Date Acomplished] based on start and finish planned dates as reference.

 

Acomplished dates can be for more or less, so I don't know how to do this, because this could be MAX or MIN values. The thing must returns the closest value does not matter if it is higher or not.

 

Please help.

1 REPLY 1
AlB
Super User
Super User

Hi @Anonymous

Try this for your columns, at least for the general idea. I haven't tested it. If you post sample data I'd be able to.

 

 

NearestStartDateAccomplished =
VAR _Dates =
    CALCULATETABLE (
        VALUES ( TableB[Start Date Acomplished] ),
        FILTER ( TableB, TableB[ID] = TableA[ID] && TableB[Name] = TableA[Name] )
    )
VAR _MinDiffDatesPrior =
    MINX (
        FILTER ( _Dates, [Start Date Acomplished] < TableA[Start Date Planned] ),
        ABS ( TableA[Start Date Planned] - [Start Date Acomplished] )
    )
VAR _MinDiffDatesPost =
    MINX (
        FILTER ( _Dates, [Start Date Acomplished] >= TableA[Start Date Planned] ),
        ABS ( TableA[Start Date Planned] - [Start Date Acomplished] )
    )
VAR _DatedDiff =
    IF (
        _MinDiffDatesPrior < _MinDiffDatesPost,
        -1 * _MinDiffDatesPrior,
        _MinDiffDatesPost
    )
RETURN
    TableA[Start Date Planned] + _DatedDiff

 

 

NearestFinishDateAccomplished =
VAR _Dates =
    CALCULATETABLE (
        VALUES ( TableB[Finish Date Acomplished] ),
        FILTER ( TableB, TableB[ID] = TableA[ID] && TableB[Name] = TableA[Name] )
    )
VAR _MinDiffDatesPrior =
    MINX (
        FILTER ( _Dates, [Finish Date Acomplished] < TableA[Finish Date Planned] ),
        ABS ( TableA[Finish Date Planned] - [Finish Date Acomplished] )
    )
VAR _MinDiffDatesPost =
    MINX (
        FILTER ( _Dates, [Finish Date Acomplished] >= TableA[Finish Date Planned] ),
        ABS ( TableA[Finish Date Planned] - [Finish Date Acomplished] )
    )
VAR _DatedDiff =
    IF (
        _MinDiffDatesPrior < _MinDiffDatesPost,
        -1 * _MinDiffDatesPrior,
        _MinDiffDatesPost
    )
RETURN
    TableA[Finish Date Planned] + _DatedDiff

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.