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, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
Lachlanpap
Frequent Visitor

Multiple Flags for same Reference Number

Hi,

 

I have three flags being Blank, Provisional and Final attached to the same reference number. The reference number can be at any three stages of coding. If the reference number has the status Final there will be two other lines one for Blank and the other for Provisional. I only want to extract the Final line of coding for the reference number and ignore Blank and Provisional. 

 

I can not just filter on Final as some of the reference numbers might only be at the Blank stage of coding or Blank and Provisional. I want to extract only the reference number applicable to the lines stage of coding. 

 

Any help would be greatly appreciated. I am assuming this problem can be solved using DAX or potentially in Power Query. 

 

Thanks

 

 

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

Hi @Lachlanpap ,


If I understand correctly, blank, provisional and final are sequential. I'm assuming the raw data looks like this;

vcgaomsft_1-1722562521598.png

PowerQuery M:

 

let
    Source = Table,
    #"Grouped Rows" = Table.Group(Source, {"reference number"}, {{"Data", each Table.LastN(_, 1)}}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Grouped Rows", "Data", {"flags"}, {"flags"})
in
    #"Expanded Data"

 

vcgaomsft_0-1722562504933.png

 

Dax:

first create a new enter table:

vcgaomsft_2-1722563613900.png

then relationship:

vcgaomsft_3-1722563646955.png

then please create a new measure:

 

Measure = 
VAR __cur_sort =  CALCULATE( MAX('DimFlag'[FlagSort]), CROSSFILTER('Table'[flags],'DimFlag'[flags],Both))
VAR __max_sort = CALCULATE( MAX('DimFlag'[FlagSort]), CROSSFILTER('Table'[flags],'DimFlag'[flags],Both) ,ALLEXCEPT('Table','Table'[reference number]),VALUES('Table'[reference number]))
VAR __result = IF( __cur_sort = __max_sort, 1)
RETURN
__result

 

and use it as table visual's filter:

vcgaomsft_4-1722563719609.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

 

View solution in original post

4 REPLIES 4
v-cgao-msft
Community Support
Community Support

Hi @Lachlanpap ,


If I understand correctly, blank, provisional and final are sequential. I'm assuming the raw data looks like this;

vcgaomsft_1-1722562521598.png

PowerQuery M:

 

let
    Source = Table,
    #"Grouped Rows" = Table.Group(Source, {"reference number"}, {{"Data", each Table.LastN(_, 1)}}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Grouped Rows", "Data", {"flags"}, {"flags"})
in
    #"Expanded Data"

 

vcgaomsft_0-1722562504933.png

 

Dax:

first create a new enter table:

vcgaomsft_2-1722563613900.png

then relationship:

vcgaomsft_3-1722563646955.png

then please create a new measure:

 

Measure = 
VAR __cur_sort =  CALCULATE( MAX('DimFlag'[FlagSort]), CROSSFILTER('Table'[flags],'DimFlag'[flags],Both))
VAR __max_sort = CALCULATE( MAX('DimFlag'[FlagSort]), CROSSFILTER('Table'[flags],'DimFlag'[flags],Both) ,ALLEXCEPT('Table','Table'[reference number]),VALUES('Table'[reference number]))
VAR __result = IF( __cur_sort = __max_sort, 1)
RETURN
__result

 

and use it as table visual's filter:

vcgaomsft_4-1722563719609.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

 

Wow, thank you very much. I used option 2 and it worked perfectly. I am now going to study the syntax in the measure. Really appreciate your help 😀

Shravan133
Solution Sage
Solution Sage

Hi,

 

Try creating a calculated column like this for example:

IsFinal =
VAR CurrentRefNumber = 'YourTable'[ReferenceNumber]
VAR HasFinal =
CALCULATE(
COUNTROWS('YourTable'),
'YourTable'[ReferenceNumber] = CurrentRefNumber,
'YourTable'[Flag] = "Final"
) > 0
RETURN
IF(
HasFinal,
IF(
'YourTable'[Flag] = "Final",
TRUE(),
FALSE()
),
FALSE()
)

This column will return TRUE if the reference number has a "Final" status and FALSE otherwise.

 

Now, you can use this calculated column to filter your data in your visuals.

 

 

Or a measure like this: 

 

FinalFlagMeasure =
IF(
COUNTROWS(
FILTER(
'YourTable',
'YourTable'[Flag] = "Final" &&
'YourTable'[ReferenceNumber] = MAX('YourTable'[ReferenceNumber])
)
) > 0,
1,
0
)

This measure returns 1 if the reference number has a "Final" status and 0 otherwise.

Thanks for your reply Shravan133. I ended up using option 2 from Gao above. I appreciate your response regardless 👍

Helpful resources

Announcements
OCT PBI Update Carousel

Power BI Monthly Update - October 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

October NL Carousel

Fabric Community Update - October 2024

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

Top Kudoed Authors