Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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
OrderID | OrderLineID | Hardware | Training |
1 | 1 | TRUE | FALSE |
1 | 2 | TRUE | FALSE |
1 | 3 | FALSE | TRUE |
Solved! Go to Solution.
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
Proud to be a Datanaut!
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
Proud to be a Datanaut!
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
39 | |
21 | |
20 | |
19 | |
13 |
User | Count |
---|---|
67 | |
54 | |
42 | |
28 | |
22 |