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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Anonymous
Not applicable

Comapre 3 rows if dates and Display the latest date row

HI

I have a table with 3 coulms having Approval date , Submitted date, Planned Date. i need to display only the row with the max date of these three date columns per each country blow is sample of my data

Reg NumCountryApproval DateSub datePlanned date
123IndiaDec 10 2022  
123India Aug 10 2022 
123India  Jun 10 2022
345US Sep 20 2022 
345US  Aug 20 2022
145France  Jun 20 2022

 

Output should be

Reg NumCountryApproval dateSubmitted datePlanned date
123IndiaDec 10 2022  
345US Sep 20 2022 
145France  Jun 20 2022
1 ACCEPTED SOLUTION
Samarth_18
Community Champion
Community Champion

Hi @Anonymous ,

 

You could create a column as below:-

Final Date = 
VAR app_date =
    CALCULATE (
        MAX ( 'Table'[Approval Date] ),
        FILTER ( 'Table', 'Table'[Reg Num] = EARLIER ( 'Table'[Reg Num] ) )
    )
VAR sub_date =
    CALCULATE (
        MAX ( 'Table'[Sub date] ),
        FILTER ( 'Table', 'Table'[Reg Num] = EARLIER ( 'Table'[Reg Num] ) )
    )
VAR plan_date =
    CALCULATE (
        MAX ( 'Table'[Planned date] ),
        FILTER ( 'Table', 'Table'[Reg Num] = EARLIER ( 'Table'[Reg Num] ) )
    )
RETURN
    MAX ( MAX ( app_date, sub_date ), plan_date )

 

Then create these measure for your date as below:-

approval_date = 
IF (
    MAX ( 'Table'[Approval Date] ) = MAX ( 'Table'[Final Date] ),
    MAX ( 'Table'[Approval Date] ),
    BLANK ()
)
planned_date = 
IF (
    MAX ( 'Table'[planned Date] ) = MAX ( 'Table'[Final Date] ),
    MAX ( 'Table'[planned Date] ),
    BLANK ()
)
sub_date = 
IF (
    MAX ( 'Table'[sub Date] ) = MAX ( 'Table'[Final Date] ),
    MAX ( 'Table'[sub Date] ),
    BLANK ()
)

Output:-

image.png

 

Refer a file below:-

 

Best Regards,
Samarth

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
Connect on Linkedin

View solution in original post

3 REPLIES 3
Ahmedx
Super User
Super User

 

 

Approval_Date = 
IF (
    CALCULATE (
        MAX ( 'tbl'[Approval Date] ),
        ALLEXCEPT ( tbl, tbl[Approval Date] )
    )
        = MAX ( 'tbl'[Approval Date] ),
    MAX ( 'tbl'[Approval Date] )
)
 ----
Planned_date = 
IF (
    CALCULATE ( MAX ( tbl[Planned date] ), ALLEXCEPT ( tbl, tbl[Planned date] ) )
        = MAX ( tbl[Planned date] ),
    MAX ( tbl[Planned date] )
)
---
Sub_date = 
IF (
    CALCULATE ( MAX ( 'tbl'[Sub date] ), ALLEXCEPT ( tbl, 'tbl'[Sub date] ) )
        = MAX ( 'tbl'[Sub date] ),
    MAX ( 'tbl'[Sub date] )
)

 

file hir:
https://dropmefiles.com/nsDa5

Pragati11
Super User
Super User

HI @Anonymous ,

You can get this by just measure creation avoiding any column creation.

Create 3 measures as follows:

 

 

# Approval Date Max = // getting logic for approval date comparison at a country level
VAR ApprovalDate_max = // getting maximum approval date at a country level
CALCULATE(MAX(PBIQueryData[Approval Date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR SubDate_max = // getting maximum substitute date at a country level
CALCULATE(MAX(PBIQueryData[Sub date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR PlannedDate_max = // getting maximum planned date at a country level
CALCULATE(MAX(PBIQueryData[Planned date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR date_comparison = // comparing all three dates to get the maximum value
IF(
    ApprovalDate_max > SubDate_max && ApprovalDate_max > PlannedDate_max,
    ApprovalDate_max,
    BLANK()
)

RETURN
date_comparison
# Substitue Date Max = // getting logic for substitute date comparison at a country level
VAR ApprovalDate_max = // getting maximum approval date at a country level
CALCULATE(MAX(PBIQueryData[Approval Date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR SubDate_max = // getting maximum substitute date at a country level
CALCULATE(MAX(PBIQueryData[Sub date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR PlannedDate_max = // getting maximum planned date at a country level
CALCULATE(MAX(PBIQueryData[Planned date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR date_comparison = // comparing all three dates to get the maximum value
IF(
    SubDate_max > ApprovalDate_max && SubDate_max > PlannedDate_max,
    SubDate_max,
    BLANK()
)

RETURN
date_comparison
# Planned Date Max = // getting logic for planned date comparison at a country level
VAR ApprovalDate_max = // getting maximum approval date at a country level
CALCULATE(MAX(PBIQueryData[Approval Date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR SubDate_max = // getting maximum substitute date at a country level
CALCULATE(MAX(PBIQueryData[Sub date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR PlannedDate_max = // getting maximum planned date at a country level
CALCULATE(MAX(PBIQueryData[Planned date]), FILTER(ALL(PBIQueryData), PBIQueryData[Country] = MAX(PBIQueryData[Country])))

VAR date_comparison = // comparing all three dates to get the maximum value
IF(
    PlannedDate_max > ApprovalDate_max && PlannedDate_max > SubDate_max,
    PlannedDate_max,
    BLANK()
)

RETURN
date_comparison

 

 

Move them to the table visual and you get the required result:

Pragati11_0-1672836174298.png

Make sure to modify the names of these measures as per your requirement and also the format of the date for them.

Hope this helps.

 

Best Regards,

Pragati Jain


MVP logo


LinkedIn | Twitter | Blog YouTube 

Did I answer your question? Mark my post as a solution! This will help others on the forum!

Appreciate your Kudos!!

Proud to be a Super User!!

Samarth_18
Community Champion
Community Champion

Hi @Anonymous ,

 

You could create a column as below:-

Final Date = 
VAR app_date =
    CALCULATE (
        MAX ( 'Table'[Approval Date] ),
        FILTER ( 'Table', 'Table'[Reg Num] = EARLIER ( 'Table'[Reg Num] ) )
    )
VAR sub_date =
    CALCULATE (
        MAX ( 'Table'[Sub date] ),
        FILTER ( 'Table', 'Table'[Reg Num] = EARLIER ( 'Table'[Reg Num] ) )
    )
VAR plan_date =
    CALCULATE (
        MAX ( 'Table'[Planned date] ),
        FILTER ( 'Table', 'Table'[Reg Num] = EARLIER ( 'Table'[Reg Num] ) )
    )
RETURN
    MAX ( MAX ( app_date, sub_date ), plan_date )

 

Then create these measure for your date as below:-

approval_date = 
IF (
    MAX ( 'Table'[Approval Date] ) = MAX ( 'Table'[Final Date] ),
    MAX ( 'Table'[Approval Date] ),
    BLANK ()
)
planned_date = 
IF (
    MAX ( 'Table'[planned Date] ) = MAX ( 'Table'[Final Date] ),
    MAX ( 'Table'[planned Date] ),
    BLANK ()
)
sub_date = 
IF (
    MAX ( 'Table'[sub Date] ) = MAX ( 'Table'[Final Date] ),
    MAX ( 'Table'[sub Date] ),
    BLANK ()
)

Output:-

image.png

 

Refer a file below:-

 

Best Regards,
Samarth

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
Connect on Linkedin

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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