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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
BenDC
Regular Visitor

Custom Column based on comparing a value against a shared identifier

Hi,

 

I have achieved this by duplicating the data source and using the GROUP BY function, however, I wondered if there was a cleaner way to achieve what I am looking for.

 

In the example below, I have a table structured for orders which can include hardware elements and training elements. I want to add a new custom column, 'Training Order'. The logic being, if there is a single Order Line on the same OrderID where Training is TRUE, add this column to all lines of the order with the value of TRUE. The reverse logic applies for FALSE if there are no lines.

 

I would like to know if there is a way to use a nested query that queries the data in the same source, without having to create a separate copy of the source and join it back in.

 

If I were writing this as an SQL query, for example, I would create a query like this:

 

SELECT

*,

Training Order = (CASE

WHEN OrderID IN (SELECT OrderID FROM Orders WHERE Training = TRUE")

THEN "TRUE" 
ELSE "FALSE"

END) 

FROM Orders 

 

OrderIDOrderLineIDHardwareTraining
11TRUEFALSE
12TRUEFALSE
13FALSETRUE
1 ACCEPTED SOLUTION
BA_Pete
Super User
Super User

Hi @BenDC ,

 

In Power Query, you can group then expand the same table.

1) Group by [Order ID] and create an 'All Rows' aggregate column

2) Add a custom column that evaluates the [Training] column of the nested tables

3) Expand your grouped rows ack out again

 

Paste this over the default code in Advanced Editor to follow the steps I took:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSAeOQoFBXIOXm6BPsqhSrA5EwwiVhDBeBKoiNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [OrderID = _t, OrderLineID = _t, Hardware = _t, Training = _t]),
    chgTypes = Table.TransformColumnTypes(Source,{{"OrderID", Int64.Type}, {"OrderLineID", Int64.Type}, {"Hardware", type logical}, {"Training", type logical}}),
    groupRows = Table.Group(chgTypes, {"OrderID"}, {{"data", each _, type table [OrderID=nullable number, OrderLineID=nullable number, Hardware=nullable logical, Training=nullable logical]}}),
    addTrainingOrder = Table.AddColumn(groupRows, "trainingOrder", each if List.Contains([data][Training], true) then "TRUE" else "FALSE"),
    expandDataCol = Table.ExpandTableColumn(addTrainingOrder, "data", {"OrderLineID", "Hardware", "Training"}, {"OrderLineID", "Hardware", "Training"})
in
    expandDataCol

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




View solution in original post

1 REPLY 1
BA_Pete
Super User
Super User

Hi @BenDC ,

 

In Power Query, you can group then expand the same table.

1) Group by [Order ID] and create an 'All Rows' aggregate column

2) Add a custom column that evaluates the [Training] column of the nested tables

3) Expand your grouped rows ack out again

 

Paste this over the default code in Advanced Editor to follow the steps I took:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSAeOQoFBXIOXm6BPsqhSrA5EwwiVhDBeBKoiNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [OrderID = _t, OrderLineID = _t, Hardware = _t, Training = _t]),
    chgTypes = Table.TransformColumnTypes(Source,{{"OrderID", Int64.Type}, {"OrderLineID", Int64.Type}, {"Hardware", type logical}, {"Training", type logical}}),
    groupRows = Table.Group(chgTypes, {"OrderID"}, {{"data", each _, type table [OrderID=nullable number, OrderLineID=nullable number, Hardware=nullable logical, Training=nullable logical]}}),
    addTrainingOrder = Table.AddColumn(groupRows, "trainingOrder", each if List.Contains([data][Training], true) then "TRUE" else "FALSE"),
    expandDataCol = Table.ExpandTableColumn(addTrainingOrder, "data", {"OrderLineID", "Hardware", "Training"}, {"OrderLineID", "Hardware", "Training"})
in
    expandDataCol

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors
Top Kudoed Authors