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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

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
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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