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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
joshua1990
Post Prodigy
Post Prodigy

GROUP table to boolean

Hi all,

I have a table that shows for each order the customer type and a specific key:

Order NrCustomerKey
555ABC-01A
555BDA-01B
556ABC-02A
557ABC-03A
558BDA-02C

 

Now I would like to group that table into this structure:

Order NrABCBDAABC KeyBDA Key
555TRUETRUEFALSETRUE
556TRUEFALSEFALSEFALSE
557TRUEFALSEFALSEFALSE
558FALSETRUEFALSETRUE

 

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?

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

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"

 

View solution in original post

1 REPLY 1
Vijay_A_Verma
Super User
Super User

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"

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors