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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Meghbajaj
Frequent Visitor

Data Transformation

I have the following data:

IDRoleManager Name
1000adminJohn
1000viewerJackson
1001adminRonnie
1002adminLillie
1003adminPaul
1003viewer

Jessica

 

And I want to achieve this final result:

IDRoleManager NameViewer Name
1000adminJohnJackson
1001adminRonnie 
1002adminLillie 
1003adminPaulJessica

 

Kindly suggest the best approach to do this. Thanks.

 

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("i45WMjQwMFDSUUpMyc3MA9Je+Rl5SrE6cPGyzNTy1CKQRGJydnE+XM4QSU9Qfl5eZipMxghJxiczJwchY4wkE5BYmoMsjrAntbg4MzlRKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Role = _t, #"Manager Name" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Role", type text}, {"Manager Name", type text}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Role] = "admin")),
    Custom1 = Table.SelectRows(#"Changed Type", each ([Role] = "viewer")),
    #"Merged Queries" = Table.NestedJoin(#"Filtered Rows", {"ID"}, Custom1, {"ID"}, "Custom1", JoinKind.LeftOuter),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Merged Queries", "Custom1", {"Manager Name"}, {"Viewer Name"})
in
    #"Expanded Custom1"

 

View solution in original post

2 REPLIES 2
CNENFRNL
Community Champion
Community Champion

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwMFDSUUpMyc3MA9Je+Rl5SrE6cPGyzNTy1CKQRGJydnE+XM4QSU9Qfl5eZipMxghJxiczJwchY4wkE5BYmoMsjrAntbg4MzlRKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Role = _t, #"Manager Name" = _t]),
    #"Pivoted Column" = Table.Pivot(Source, List.Distinct(Source[Role]), "Role", "Manager Name")
in
    #"Pivoted Column"

CNENFRNL_0-1663157049390.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

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("i45WMjQwMFDSUUpMyc3MA9Je+Rl5SrE6cPGyzNTy1CKQRGJydnE+XM4QSU9Qfl5eZipMxghJxiczJwchY4wkE5BYmoMsjrAntbg4MzlRKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Role = _t, #"Manager Name" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Role", type text}, {"Manager Name", type text}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Role] = "admin")),
    Custom1 = Table.SelectRows(#"Changed Type", each ([Role] = "viewer")),
    #"Merged Queries" = Table.NestedJoin(#"Filtered Rows", {"ID"}, Custom1, {"ID"}, "Custom1", JoinKind.LeftOuter),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Merged Queries", "Custom1", {"Manager Name"}, {"Viewer Name"})
in
    #"Expanded Custom1"

 

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors