Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi all,
I have a table that shows for each order the customer type and a specific key:
Order Nr | Customer | Key |
555 | ABC-01 | A |
555 | BDA-01 | B |
556 | ABC-02 | A |
557 | ABC-03 | A |
558 | BDA-02 | C |
Now I would like to group that table into this structure:
Order Nr | ABC | BDA | ABC Key | BDA Key |
555 | TRUE | TRUE | FALSE | TRUE |
556 | TRUE | FALSE | FALSE | FALSE |
557 | TRUE | FALSE | FALSE | FALSE |
558 | FALSE | TRUE | FALSE | TRUE |
First I need two columns: [ABC] and [BDA] as a TRUE/FALSE if in column "Customer" the text begins with ABC or BDA.
Then I need again two columns: [ABC Key] and [BDA Key] if per Order and per Customer we can find a recods with Key "B" or "C".
How is this possible in Power Query?
Solved! Go to Solution.
See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjU1VdJRcnRy1jUwBDGUYnVggk4ujhBBJ6igGUylEZJKc5igMZKgBUw7SKWzUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Order Nr" = _t, Customer = _t, Key = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Order Nr", Int64.Type}, {"Customer", type text}, {"Key", type text}}),
CustomerList = List.Buffer(List.Zip({#"Changed Type"[Order Nr],List.Transform(#"Changed Type"[Customer],each Text.Start(_,3))})),
KeyList = List.Buffer(List.Zip({#"Changed Type"[Order Nr],List.Transform(#"Changed Type"[Customer],each Text.Start(_,3)), #"Changed Type"[Key]})),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"Customer", "Key"}),
#"Removed Duplicates" = Table.Distinct(#"Removed Columns"),
#"Added Custom" = Table.AddColumn(#"Removed Duplicates", "ABC", each List.Contains(CustomerList,{[Order Nr]}&{"ABC"})),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "BDA", each List.Contains(CustomerList,{[Order Nr]}&{"BDA"})),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "ABC Key#(tab)", each List.ContainsAny(KeyList,{{[Order Nr]}&{"ABC"}&{"B"},{[Order Nr]}&{"ABC"}&{"C"}})),
#"Added Custom3" = Table.AddColumn(#"Added Custom2", "BDA Key", each List.ContainsAny(KeyList,{{[Order Nr]}&{"BDA"}&{"B"},{[Order Nr]}&{"BDA"}&{"C"}}))
in
#"Added Custom3"
See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjU1VdJRcnRy1jUwBDGUYnVggk4ujhBBJ6igGUylEZJKc5igMZKgBUw7SKWzUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Order Nr" = _t, Customer = _t, Key = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Order Nr", Int64.Type}, {"Customer", type text}, {"Key", type text}}),
CustomerList = List.Buffer(List.Zip({#"Changed Type"[Order Nr],List.Transform(#"Changed Type"[Customer],each Text.Start(_,3))})),
KeyList = List.Buffer(List.Zip({#"Changed Type"[Order Nr],List.Transform(#"Changed Type"[Customer],each Text.Start(_,3)), #"Changed Type"[Key]})),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"Customer", "Key"}),
#"Removed Duplicates" = Table.Distinct(#"Removed Columns"),
#"Added Custom" = Table.AddColumn(#"Removed Duplicates", "ABC", each List.Contains(CustomerList,{[Order Nr]}&{"ABC"})),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "BDA", each List.Contains(CustomerList,{[Order Nr]}&{"BDA"})),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "ABC Key#(tab)", each List.ContainsAny(KeyList,{{[Order Nr]}&{"ABC"}&{"B"},{[Order Nr]}&{"ABC"}&{"C"}})),
#"Added Custom3" = Table.AddColumn(#"Added Custom2", "BDA Key", each List.ContainsAny(KeyList,{{[Order Nr]}&{"BDA"}&{"B"},{[Order Nr]}&{"BDA"}&{"C"}}))
in
#"Added Custom3"
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
10 | |
8 | |
7 | |
6 | |
6 |