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
bman6074
Helper I
Helper I

Transpose Table

Hi,

Is there a way to transpose/pivot this (Current picture) table to (Transpose picture) So each name is across the top and the usage risk scores listed below?

Then ultimatly I want to take highest number to from each list as shown in (Finish picture).

 

Current

Current.jpg

TransposeNew.jpg

Finsh

Then.jpg

 
2 ACCEPTED SOLUTIONS

Hi @bman6074 ,

 

We can transpose it by using "Transform" - "Povit Column" in Power Query Editor, then select maximum as aggreration function:

 

4.jpg5.jpg

 

Or we can append this step in your queries

let
Source = Sql.Databases("database.power bi"),
Powerbi= Source{[Name="powerbi"]}[Data],
snow_AllRelationshipsKeyTable = powerbi{[Schema="snow",Item="AllRelationshipsKeyTable"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(snow_AllRelationshipsKeyTable,{{"EOL", type date}, {"EOSL", type date}, {"LCS_GA", type date}}),
#"Removed Other Columns" = Table.SelectColumns(#"Changed Type",{"Name", "Usage_Risk_Score"}),
PivotStep = Table.Pivot(#"Removed Other Columns", List.Distinct(#"Changed Type"[Name]), "Name", "Usage_Risk_Score", List.Max)
in
PivotStep

 


By the way, PBIX file as attached.


Best regards,

 

Community Support Team _ Dong Li
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

Hi @bman6074 ,

 

Please try to change the data type of Usage_Risk_Score column to whole number before unpivot,

 

1.jpg

 

Or use the following query:

 

let
Source = Sql.Databases("database.power bi"),
Powerbi= Source{[Name="powerbi"]}[Data],
snow_AllRelationshipsKeyTable = powerbi{[Schema="snow",Item="AllRelationshipsKeyTable"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(snow_AllRelationshipsKeyTable,{{"EOL", type date}, {"EOSL", type date}, {"LCS_GA", type date}}),
#"Removed Other Columns" = Table.SelectColumns(#"Changed Type",{"Name", "Usage_Risk_Score"}),
ChangeType = Table.TransformColumnTypes(#"Removed Other Columns",{{"Name", type text}, {"Usage_Risk_Score", Int64.Type}}),
PivotStep = Table.Pivot(#"ChangeType", List.Distinct(#"Changed Type"[Name]), "Name", "Usage_Risk_Score", List.Max)
in
PivotStep

 


Best regards,

Community Support Team _ Dong Li
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

6 REPLIES 6
camargos88
Community Champion
Community Champion

Hi @bman6074 ,

 

Try this code on Advanced Editor:

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcixKzkgtUnAPclbSUcorzclRitXBI5pfrBAMlEopzcnMS1dwSSxJBCowhcgGeTo5oigvLkjNU3DJLC4pygzLTC1X0EXiABUaEaXK0ICwMoXggsSSzMQcBc+8ktSitMTkVISrSNYHsjAWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Name = _t, Usage_Risk_Score = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Usage_Risk_Score", Int64.Type}}),
#"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Name]), "Name", "Usage_Risk_Score", List.Max)
in
#"Pivoted Column"

 

Ricardo



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

Proud to be a Super User!



Hi Ricardo,

thanks for replying.

How do i add it to the current code in the advance editor?

 

let
Source = Sql.Databases("database.power bi"),
Powerbi= Source{[Name="powerbi"]}[Data],
snow_AllRelationshipsKeyTable = powerbi{[Schema="snow",Item="AllRelationshipsKeyTable"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(snow_AllRelationshipsKeyTable,{{"EOL", type date}, {"EOSL", type date}, {"LCS_GA", type date}}),
#"Removed Other Columns" = Table.SelectColumns(#"Changed Type",{"Name", "Usage_Risk_Score"})
in
#"Removed Other Columns"

Hi @bman6074 ,

 

We can transpose it by using "Transform" - "Povit Column" in Power Query Editor, then select maximum as aggreration function:

 

4.jpg5.jpg

 

Or we can append this step in your queries

let
Source = Sql.Databases("database.power bi"),
Powerbi= Source{[Name="powerbi"]}[Data],
snow_AllRelationshipsKeyTable = powerbi{[Schema="snow",Item="AllRelationshipsKeyTable"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(snow_AllRelationshipsKeyTable,{{"EOL", type date}, {"EOSL", type date}, {"LCS_GA", type date}}),
#"Removed Other Columns" = Table.SelectColumns(#"Changed Type",{"Name", "Usage_Risk_Score"}),
PivotStep = Table.Pivot(#"Removed Other Columns", List.Distinct(#"Changed Type"[Name]), "Name", "Usage_Risk_Score", List.Max)
in
PivotStep

 


By the way, PBIX file as attached.


Best regards,

 

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi Community Support Team _ Dong Li

Thanks for the reply. Unfortunatly that doesn't acheive what I need. Its not ending with highest value in the list of usage risk score. 

For example the Advantex Gas modile has 4 scores and 2 are 10. Result should end with highest value which would be 10 but it ended up with 5

Results.jpg

 

Hi @bman6074 ,

 

Please try to change the data type of Usage_Risk_Score column to whole number before unpivot,

 

1.jpg

 

Or use the following query:

 

let
Source = Sql.Databases("database.power bi"),
Powerbi= Source{[Name="powerbi"]}[Data],
snow_AllRelationshipsKeyTable = powerbi{[Schema="snow",Item="AllRelationshipsKeyTable"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(snow_AllRelationshipsKeyTable,{{"EOL", type date}, {"EOSL", type date}, {"LCS_GA", type date}}),
#"Removed Other Columns" = Table.SelectColumns(#"Changed Type",{"Name", "Usage_Risk_Score"}),
ChangeType = Table.TransformColumnTypes(#"Removed Other Columns",{{"Name", type text}, {"Usage_Risk_Score", Int64.Type}}),
PivotStep = Table.Pivot(#"ChangeType", List.Distinct(#"Changed Type"[Name]), "Name", "Usage_Risk_Score", List.Max)
in
PivotStep

 


Best regards,

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.