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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
adventurer7
Helper I
Helper I

Need Help on Data Transformation

Happy holidays everyone! Need help on transforming this data that comes from the client tool as follows :

 

Name1.11.1 Score1.21.2 Score2.12.2 Score
Name 1Attendance100%Quality85%Adherence60%
Name 2Attendance50%Productivity0%SLA75%

 

The output I am trying to achieve would be :

NameAttributeScore
Name 1Attendance100%
Name 1Quality85%
Name 1Adherence60%
Name 2Attendance50%
Name 2Productivity0%
Name 2SLA75%

Tried unpivoting columns/unpivoting other columns one column at a time and also simultaneously but I'm not getting the desired result. To add context, I am required to create a visual to show the count of 0% score instances per attribute/metric.

Any solution would be a huge help 🙇 

1 ACCEPTED SOLUTION
bolfri
Super User
Super User

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8kvMTVUwVNJRciwpSc1LScxLTgVyDA0MdAwMVIGswNLEnMySSiDLwhQq5JiSkVqUClFoBlEXqwM1yQjdJFOYQQFF+SmlySWZZRDTYMLBPo5A0hxidmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, #"1.1" = _t, #"1.1 Score" = _t, #"1.2" = _t, #"1.2 Score" = _t, #"2.2" = _t, #"2.2 Score" = _t]),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {"Name"}, "Context", "Value"),
    #"Added Custom" = Table.AddColumn(#"Unpivoted Columns", "Type", each if Text.Contains([Context],"Score") then "Score" else "Attribute"),
    #"Pivoted Column" = Table.Pivot(#"Added Custom", List.Distinct(#"Added Custom"[Type]), "Type", "Value"),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Pivoted Column", {{"Context", each Text.BeforeDelimiter(_, " "), type text}}),
    #"Grouped Rows" = Table.Group(#"Extracted Text Before Delimiter", {"Name", "Context"}, {{"Attribute", each List.Max([Attribute]), type nullable text}, {"Score", each List.Max([Score]), type nullable number}})
in
    #"Grouped Rows"

 

 

Before:

bolfri_0-1671837374084.png

 

After:

bolfri_1-1671837385851.png

 

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

4 REPLIES 4
adventurer7
Helper I
Helper I

thank you sir! awesome work.. had to look at each step to understand what happened

pretty creative to use the 1.1 etc to group columns together.. appreciate it!

I am happy to hear that I could help. 🙂 If some steps are unclear for you (why I did that) - just ask.

P.S. It's not important, but I am a girl 😁 Not "sir".





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




so sorry >< thanks a lot ms. bolfri and happy holiday

bolfri
Super User
Super User

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8kvMTVUwVNJRciwpSc1LScxLTgVyDA0MdAwMVIGswNLEnMySSiDLwhQq5JiSkVqUClFoBlEXqwM1yQjdJFOYQQFF+SmlySWZZRDTYMLBPo5A0hxidmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, #"1.1" = _t, #"1.1 Score" = _t, #"1.2" = _t, #"1.2 Score" = _t, #"2.2" = _t, #"2.2 Score" = _t]),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {"Name"}, "Context", "Value"),
    #"Added Custom" = Table.AddColumn(#"Unpivoted Columns", "Type", each if Text.Contains([Context],"Score") then "Score" else "Attribute"),
    #"Pivoted Column" = Table.Pivot(#"Added Custom", List.Distinct(#"Added Custom"[Type]), "Type", "Value"),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Pivoted Column", {{"Context", each Text.BeforeDelimiter(_, " "), type text}}),
    #"Grouped Rows" = Table.Group(#"Extracted Text Before Delimiter", {"Name", "Context"}, {{"Attribute", each List.Max([Attribute]), type nullable text}, {"Score", each List.Max([Score]), type nullable number}})
in
    #"Grouped Rows"

 

 

Before:

bolfri_0-1671837374084.png

 

After:

bolfri_1-1671837385851.png

 

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.