Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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 Num | Country | Approval Date | Sub date | Planned date |
123 | India | Dec 10 2022 | ||
123 | India | Aug 10 2022 | ||
123 | India | Jun 10 2022 | ||
345 | US | Sep 20 2022 | ||
345 | US | Aug 20 2022 | ||
145 | France | Jun 20 2022 |
Output should be
Reg Num | Country | Approval date | Submitted date | Planned date |
123 | India | Dec 10 2022 | ||
345 | US | Sep 20 2022 | ||
145 | France | Jun 20 2022 |
Solved! Go to Solution.
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:-
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
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
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:
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.
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:-
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
User | Count |
---|---|
61 | |
59 | |
56 | |
38 | |
29 |
User | Count |
---|---|
83 | |
62 | |
45 | |
40 | |
39 |