Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I created a version of the column with the help of the community where the calaculation of the latest and previous date are based on another column but I need to incorporate an additional column to the equation as I need a combination of the column along with the dynamic slicer selection to determine the latest and previous values.
The original DAX is
_Rank_P =
VAR _rank =
RANKX ( FILTER ( ALL ( 'Table' ), 'Table'[flg] = "P" ), [Date],, DESC, DENSE )
VAR _isP =
IF ( [flg] = "P", _rank, BLANK () )
RETURN
_isP
_Need Column =
SWITCH (
TRUE (),
'Table'[_Rank_P] = 1, "Lastest",
'Table'[_Rank_P] = 2, "Previous",
FORMAT ( 'Table'[Date], "General Date" )
)
but now I need a DAX formula where it incorporates an addtional column based on the dynamic user slection to get the latest and previous time. Any Help would be appreciated. The new column has column name as State and values as PA, TX, FL, etc
Solved! Go to Solution.
Hi @sridharpolina ,
Please change the measure to a column.
Column =
var _rankx=RANKX(filter(ALLSELECTED('Table'),'Table'[State]=EARLIER('Table'[State])),'Table'[AsOfDate],,DESC,Dense)
RETURN
IF(_rankx=1,"Latest Runtime",IF(_rankx=2,"Previous Runtime",FORMAT(('Table'[AsOfDate]),"General Date")))
_Rank_P =
VAR _rank =
RANKX ( FILTER ( 'Table' , OR(('Table'[Flg] = "P"),Table[State]=EARLIER(Table[State]))), 'Table'[AsOfDate],, DESC, DENSE )
VAR _isP =
IF ( 'Schedules'[Flg] = "P" , _rank, BLANK () )
RETURN
_isP
Best Regards
Community Support Team _ Polly
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi @sridharpolina ,
Please have a try.
Create a measure.
_Rank_P =
VAR _rank =
RANKX ( FILTER ( ALL ( 'Table' ), 'Table'[flg] = "P" ), MAX('Table'[date]),, DESC, DENSE )
VAR _isP =
IF ( MAX('Table'[Flg]) = "P", _rank, BLANK () )
RETURN
SWITCH (
TRUE (),
MAX('Table'[Rank_P]) = 1, "Lastest",
MAX( 'Table'[Rank_P] )= 2, "Previous",
FORMAT ( MAX('Table'[date]), "General Date" )
)
If I have misunderstood your meaning, please provide your desired output with more details and you sample pbix file without privacy information.
Best Regards
Community Support Team _ Polly
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
I was calculating the Rank_P column but not getting the desired output as it does not incorporate the State column. I need the latest datetime for any state tagged as Latest and the second datetime as previous. So irrespective of the datetimes I need the state to determine if the datetime is tagged as latest or not. The data below is the table I have as I was calaculating the Rank_P using DAX.
AsOfDate | State | Flg | Current Date-Rollup | Desired Date-Rollup |
6/13/2022 7:00 | D | P | Latest Runtime | Latest Runtime |
6/13/2022 7:00 | L | P | Latest Runtime | Latest Runtime |
6/13/2022 7:00 | M | P | Latest Runtime | Latest Runtime |
6/13/2022 7:00 | MR | P | Latest Runtime | Latest Runtime |
6/13/2022 7:00 | PetChem | P | Latest Runtime | Latest Runtime |
6/13/2022 7:00 | ST | P | Latest Runtime | Latest Runtime |
6/13/2022 7:00 | TR | P | Latest Runtime | Latest Runtime |
6/13/2022 6:00 | WN | P | Previous Runtime | Latest Runtime |
6/10/2022 7:00 | D | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 7:00 | L | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 7:00 | M | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 7:00 | MR | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 7:00 | PetChem | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 7:00 | ST | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 7:00 | TR | P | 6/10/2022 7:00 | Previous Runtime |
6/10/2022 6:00 | WN | P | 6/10/2022 6:00 | Previous Runtime |
6/9/2022 7:00 | D | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 7:00 | L | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 7:00 | M | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 7:00 | MR | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 7:00 | PetChem | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 7:00 | ST | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 7:00 | TR | P | 6/9/2022 7:00 | 6/9/2022 7:00 |
6/9/2022 6:00 | WN | P | 6/9/2022 6:00 | 6/9/2022 6:00 |
Hi @sridharpolina ,
Please have a try.
Create a measure.
Measure =
VAR _rankx =
RANKX (
FILTER (
ALLSELECTED ( 'Table' ),
'Table'[State] = SELECTEDVALUE ( 'Table'[State] )
),
CALCULATE ( MAX ( 'Table'[AsOfDate] ) ),
,
DESC,
DENSE
)
RETURN
IF (
_rankx = 1,
"Latest Runtime",
IF (
_rankx = 2,
"Previous Runtime",
FORMAT ( MAX ( 'Table'[AsOfDate] ), "General Date" )
)
)
Best Regards
Community Support Team _ Polly
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Thanks for all your help but I need a calculated column as an output since I need to use that column in a slicer. I tried to rank using the DAX code below but its not giving me the right output. Can you modify that query to reflect the state so I could get the desired output as a calculated column
_Rank_P =
VAR _rank =
RANKX ( FILTER ( ALL ( 'Table' ), OR(('Table'[Flg] = "P"),Table[State]=SELECTEDVALUE(Table[State]))), 'Table'[AsOfDate],, DESC, DENSE )
VAR _isP =
IF ( 'Schedules'[Flg] = "P" , _rank, BLANK () )
RETURN
_isP
Hi @sridharpolina ,
Please change the measure to a column.
Column =
var _rankx=RANKX(filter(ALLSELECTED('Table'),'Table'[State]=EARLIER('Table'[State])),'Table'[AsOfDate],,DESC,Dense)
RETURN
IF(_rankx=1,"Latest Runtime",IF(_rankx=2,"Previous Runtime",FORMAT(('Table'[AsOfDate]),"General Date")))
_Rank_P =
VAR _rank =
RANKX ( FILTER ( 'Table' , OR(('Table'[Flg] = "P"),Table[State]=EARLIER(Table[State]))), 'Table'[AsOfDate],, DESC, DENSE )
VAR _isP =
IF ( 'Schedules'[Flg] = "P" , _rank, BLANK () )
RETURN
_isP
Best Regards
Community Support Team _ Polly
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi @sridharpolina ,
What is your desired output? Could you please provide an image with your desired output?
Best Regards
Community Support Team _ Polly
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
The output should look like green date rollup which includes the state as well to calculate the latest time instead of just the date. The desired output is in green while the current output is in red. Any help is appreciated.Thanks
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
105 | |
99 | |
98 | |
38 | |
37 |
User | Count |
---|---|
154 | |
120 | |
73 | |
73 | |
63 |