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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

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
Community Champion
Community Champion

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
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors