cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
coding
Frequent Visitor

Show Last Value based on Flag

Hi all,

 

I have this table:

coding_0-1669731618903.png

 

and I want to create a flag that shows the last value based on the last StartDate value and the last EndDate value to show me the last success status. 

The flag value "2" is correct, that is when it shows the last pipeline that is still in progress. But I wanted it to show the last status for the previous pipelines, in this case "Succeeded" for the last date of StartDate and EndDate. (the yellow lines would be the output I intended)

 

When the Pipeline2 ends and has the state of success, it will define the value "3" and the next pipeline that will be InProgress will have the value "2"

The Flag formula (calculated column):

 

 

Flag = 
SWITCH (
    TRUE (),
        'Table'[Status] = "Succeeded" &&
         MAXX (
            SUMMARIZE (
                'Table',
                'Table'[PipelineName]
            ),
            MAX ( 'Table'[EndDate] )
        )
        && MAXX (
            SUMMARIZE (
                'Table',
                'Table'[PipelineName]
            ),
            MAX ( 'Table'[StartDate] ))
            && YEAR( 'Table'[EndDate] ) <> 2999
        , 3,
         'Table'[StartDate] = MAX ( 'Table'[StartDate] )
        && 'Table'[EndDate] = BLANK ()
        && 'Table'[Status] = "InProgress", 2,
       0
)

 

 


The Source Table:

PipelineNameStatusStartDateEndDate
Pipeline1Succeeded28/11/2022 10:1228/11/2022 10:12
Pipeline1InProgress28/11/2022 10:1231/12/2999 12:00
Pipeline1Succeeded28/11/2022 10:1228/11/2022 10:26
Pipeline1InProgress28/11/2022 10:1231/12/2999 12:00
Pipeline1Succeeded28/11/2022 10:1228/11/2022 10:26
Pipeline1InProgress28/11/2022 10:1231/12/2999 12:00
Pipeline1Succeeded28/11/2022 10:2628/11/2022 10:30
Pipeline1InProgress28/11/2022 10:2631/12/2999 12:00
Pipeline1Succeeded28/11/2022 10:2628/11/2022 11:23
Pipeline1InProgress28/11/2022 10:2631/12/2999 12:00
Pipeline1Succeeded28/11/2022 10:2628/11/2022 10:30
Pipeline1InProgress28/11/2022 10:2631/12/2999 12:00
Pipeline2Succeeded28/11/2022 11:3528/11/2022 12:07
Pipeline2InProgress28/11/2022 11:3531/12/2999 12:00
Pipeline2Succeeded28/11/2022 12:0728/11/2022 12:17
Pipeline2InProgress28/11/2022 12:0731/12/2999 12:00
Pipeline2Succeeded28/11/2022 12:1728/11/2022 12:19
Pipeline2InProgress28/11/2022 12:1731/12/2999 12:00
Pipeline2InProgress28/11/2022 12:1931/12/2999 12:00


Can anyone please help me in achieving this?

 

Thank you and kind regards!

1 ACCEPTED SOLUTION
v-stephen-msft
Community Support
Community Support

Hi @coding ,

 

For your case, it's suggested that you create an index column group by Pipeline name in Power Query first.

Steps of add the index column:

vstephenmsft_0-1669796722772.pngvstephenmsft_1-1669796734149.pngvstephenmsft_2-1669796767964.pngvstephenmsft_3-1669796789873.png

vstephenmsft_4-1669796799762.png

Click "Close&Apply" and go back to Power BI Desktop.

Then create a calculated column.

flag = var _max=CALCULATE(MAX('Table'[Index]),FILTER('Table',[PipelineName]=EARLIER('Table'[PipelineName])))
var _status=CALCULATE(MAX('Table'[Status]),FILTER('Table',[PipelineName]=EARLIER('Table'[PipelineName])&&[Index]=_max))
return IF(_max=[Index],SWITCH(_status,"Succeeded",3,"InProgress",2),0)

vstephenmsft_5-1669797110400.png

 

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-stephen-msft
Community Support
Community Support

Hi @coding ,

 

For your case, it's suggested that you create an index column group by Pipeline name in Power Query first.

Steps of add the index column:

vstephenmsft_0-1669796722772.pngvstephenmsft_1-1669796734149.pngvstephenmsft_2-1669796767964.pngvstephenmsft_3-1669796789873.png

vstephenmsft_4-1669796799762.png

Click "Close&Apply" and go back to Power BI Desktop.

Then create a calculated column.

flag = var _max=CALCULATE(MAX('Table'[Index]),FILTER('Table',[PipelineName]=EARLIER('Table'[PipelineName])))
var _status=CALCULATE(MAX('Table'[Status]),FILTER('Table',[PipelineName]=EARLIER('Table'[PipelineName])&&[Index]=_max))
return IF(_max=[Index],SWITCH(_status,"Succeeded",3,"InProgress",2),0)

vstephenmsft_5-1669797110400.png

 

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
PBI Sept Update Carousel

Power BI September 2023 Update

Take a look at the September 2023 Power BI update to learn more.

Learn Live

Learn Live: Event Series

Join Microsoft Reactor and learn from developers.

Dashboard in a day with date

Exclusive opportunity for Women!

Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!

Top Solution Authors