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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Turn marks(x) of mapping table to a colummn

Hey guys,

 

i have a Excel File, which is used by the sales team to map leads/upcoming project to internal project roles, which are needed in the upcoming projects. The sales team useses "x" in the column of the project role, if this role is needed in the possible project. My goal ist to transform all marked ("x") roles into a column.

 

LeadsRole1Role2Role3Role4
L1xxx 
L2   x
L3xx  

 

LeadsRoles needed
L1Role1, Role2, Role3
L2Role4
L3Role1, Role2

 

Thank you for your help! 😉

1 ACCEPTED SOLUTION
v-eqin-msft
Community Support
Community Support

Hi @Anonymous ,

 

You can create a new blank query and paste the whole M syntax in the Advanced Editor :

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8jFU0lGqQMIKSrE6QGEjMBOBKyDCxigqwapjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Leads = _t, Role1 = _t, Role2 = _t, Role3 = _t, Role4 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Leads", type text}, {"Role1", type text}, {"Role2", type text}, {"Role3", type text}, {"Role4", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Leads"}, "Attribute", "Value"),
    #"Filtered Rows" =Table.SelectColumns( Table.SelectRows(#"Unpivoted Other Columns", each ([Value] = "x")), {"Leads","Attribute" }),
    #"Grouped Rows" = Table.Group(#"Filtered Rows", {"Leads"}, {{"Roles Needed", each Text.Combine([Attribute],", ") ,type text}})
in
    #"Grouped Rows"

Eyelyn9_0-1658458301465.png    Eyelyn9_3-1658458452587.png

 

Output:

Eyelyn9_5-1658458756403.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-eqin-msft
Community Support
Community Support

Hi @Anonymous ,

 

You can create a new blank query and paste the whole M syntax in the Advanced Editor :

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8jFU0lGqQMIKSrE6QGEjMBOBKyDCxigqwapjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Leads = _t, Role1 = _t, Role2 = _t, Role3 = _t, Role4 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Leads", type text}, {"Role1", type text}, {"Role2", type text}, {"Role3", type text}, {"Role4", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Leads"}, "Attribute", "Value"),
    #"Filtered Rows" =Table.SelectColumns( Table.SelectRows(#"Unpivoted Other Columns", each ([Value] = "x")), {"Leads","Attribute" }),
    #"Grouped Rows" = Table.Group(#"Filtered Rows", {"Leads"}, {{"Roles Needed", each Text.Combine([Attribute],", ") ,type text}})
in
    #"Grouped Rows"

Eyelyn9_0-1658458301465.png    Eyelyn9_3-1658458452587.png

 

Output:

Eyelyn9_5-1658458756403.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors