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

Prioritising return value according to column

Hi,

 

I'm trying to return a single record per asset/date according to its source, with one source favoured over another (discarded record bolded below)...

 

Raw table:

ASSET        DATE                SOURCE        VALUE        
Asset101/06/2021A10
Asset101/06/2021B15
Asset102/06/2021B12
Asset201/06/2021A23
Asset202/06/2021A20
Asset301/06/2021C50
Asset401/06/2021D70


Desired outcome:

ASSET        DATE                SOURCE        VALUE        
Asset101/06/2021A10
Asset102/06/2021B12
Asset201/06/2021A23
Asset202/06/2021A20
Asset301/06/2021C50
Asset401/06/2021D70

 

I don't need to know the final [SOURCE] in the visualisation, however if source A doesnt have a value for the Asset/Date combination, it should then fallback to source B. There's also a [SOURCE] C & D, however I'm happy to ignore them as only sources A & B overlap in my example.

1 ACCEPTED SOLUTION
Vera_33
Solution Sage
Solution Sage

Hi @PELNZ_kjm 

 

Here is one way

 

Vera_33_0-1623641239793.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WciwuTi0xVNJRMjDUNzDTNzIwAnEcgdjQQClWB5cCJ5ACUzQFRugKjBAKjLBZYWSMpsAIXQGSG4zRTXAGYlMkBSboClyA2ByoIBYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ASSET = _t, DATE = _t, SOURCE = _t, VALUE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ASSET", type text}, {"DATE", type date}, {"SOURCE", type text}, {"VALUE", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ASSET", "DATE"}, {{"allrows", each _, type table }}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each if List.ContainsAll( [allrows][SOURCE],{"A","B"}) then Table.SelectRows([allrows], each [SOURCE] <>"B") else [allrows]),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"ASSET", "DATE", "SOURCE", "VALUE"}, {"ASSET", "DATE", "SOURCE", "VALUE"})
in
    #"Expanded Custom"

 

View solution in original post

2 REPLIES 2
Vera_33
Solution Sage
Solution Sage

Hi @PELNZ_kjm 

 

Here is one way

 

Vera_33_0-1623641239793.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WciwuTi0xVNJRMjDUNzDTNzIwAnEcgdjQQClWB5cCJ5ACUzQFRugKjBAKjLBZYWSMpsAIXQGSG4zRTXAGYlMkBSboClyA2ByoIBYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ASSET = _t, DATE = _t, SOURCE = _t, VALUE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ASSET", type text}, {"DATE", type date}, {"SOURCE", type text}, {"VALUE", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ASSET", "DATE"}, {{"allrows", each _, type table }}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each if List.ContainsAll( [allrows][SOURCE],{"A","B"}) then Table.SelectRows([allrows], each [SOURCE] <>"B") else [allrows]),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"ASSET", "DATE", "SOURCE", "VALUE"}, {"ASSET", "DATE", "SOURCE", "VALUE"})
in
    #"Expanded Custom"

 

View solution in original post

Thanks Vera, I've discovered further issues with visualising due to the data structure, however this achieves exactly what I outlined 🙂

Helpful resources

Announcements
MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Power Query PA Forum 768x460.png

Check it out!

Did you know that you can visit the Power Query Forum in Power BI and now Power Apps

Top Solution Authors
Top Kudoed Authors