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.
I have the following data:
ID | Role | Manager Name |
1000 | admin | John |
1000 | viewer | Jackson |
1001 | admin | Ronnie |
1002 | admin | Lillie |
1003 | admin | Paul |
1003 | viewer | Jessica |
And I want to achieve this final result:
ID | Role | Manager Name | Viewer Name |
1000 | admin | John | Jackson |
1001 | admin | Ronnie | |
1002 | admin | Lillie | |
1003 | admin | Paul | Jessica |
Kindly suggest the best approach to do this. Thanks.
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("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"
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"
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! |
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"
Check out the July 2025 Power BI update to learn about new features.