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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Custom Column to return value depending on rows value

Hi Everyone,

 

I have a table of many SKU's with a status column, and its value. I want to create a custom column that evaluates the value of all rows per SKU. When at least one status is TRUE, then the value of Check column is TRUE, if all the values are FALSE, then false, and if all the values are Uknown, then uknown. How can I create that column using Power query? 

 

Thanks!

 

SKUStatusValueCheck
1001ATRUETRUE
1001BTRUETRUE
1001CTRUETRUE
1001DFALSETRUE
1001ETRUETRUE
1001FTRUETRUE
1001GUNKNOWNTRUE
1002AFALSEFALSE
1002BFALSEFALSE
1003AUNKNOWNTRUE 
1003BUNKNOWNTRUE 
1003CTRUETRUE 
1004AUNKNOWNUNKNOWN
1004BUNKNOWNUNKNOWN
1 ACCEPTED SOLUTION
Vera_33
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

One way to do it, group by SKU and check the value, then join. Do you have cases that not all are FALSE or UNKNOWN, say 1 FALSE + 1 UNKNOWN?

Vera_33_0-1645249202608.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwMFTSUXIE4pCgUFelWB24mBMWMWcsYi5A7OboE4wi6IpFoRsWMXcgDvXz9vMP94MJG0Hdg2KmEdRBKILGUJVoBhhD1WIRRne/CXYTTNBNiAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [SKU = _t, Status = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"SKU", Int64.Type}, {"Status", type text}, {"Value", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"SKU"}, {{"Check", each if List.Contains( [Value], "TRUE") then "TRUE" 
else List.Distinct([Value]){0}}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"SKU"}, #"Grouped Rows", {"SKU"}, "Grouped Rows", JoinKind.LeftOuter),
    #"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"Check"}, {"Check"})
in
    #"Expanded Grouped Rows"

 

View solution in original post

1 REPLY 1
Vera_33
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

One way to do it, group by SKU and check the value, then join. Do you have cases that not all are FALSE or UNKNOWN, say 1 FALSE + 1 UNKNOWN?

Vera_33_0-1645249202608.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwMFTSUXIE4pCgUFelWB24mBMWMWcsYi5A7OboE4wi6IpFoRsWMXcgDvXz9vMP94MJG0Hdg2KmEdRBKILGUJVoBhhD1WIRRne/CXYTTNBNiAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [SKU = _t, Status = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"SKU", Int64.Type}, {"Status", type text}, {"Value", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"SKU"}, {{"Check", each if List.Contains( [Value], "TRUE") then "TRUE" 
else List.Distinct([Value]){0}}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"SKU"}, #"Grouped Rows", {"SKU"}, "Grouped Rows", JoinKind.LeftOuter),
    #"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"Check"}, {"Check"})
in
    #"Expanded Grouped Rows"

 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.

Top Solution Authors