Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Vote for your favorite vizzies from the Power BI Dataviz World Championship submissions. Vote now!

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
Resident Rockstar
Resident Rockstar

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
Resident Rockstar
Resident Rockstar

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"

 

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

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

Vote for your favorite vizzies from the Power BI World Championship submissions!

Sticker Challenge 2026 Carousel

Join our Community Sticker Challenge 2026

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

January Power BI Update Carousel

Power BI Monthly Update - January 2026

Check out the January 2026 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.