cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
PiyushBQ
Helper I
Helper I

Converting List to Meaningful Data

Hi,

I have this table:

 

DateABC
5-Jan943133
6-Jan248118
DateBDA
7-Jan1710507
8-Jan1412574

 

The desired output looks like the following:

 

DateItemValue
5-JanA9
5-JanB43
5-JanC133
6-JanA2
6-JanB48
6-JanC118
7-JanA7
7-JanB17
7-JanD1050
8-JanA4
8-JanB14
8-JanD1257

 

How do you suggest I go on about this? Unpivoting obviously doesn't work. 

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

Hi @PiyushBQ 

Copy and paste my query in advanced editor

Capture6.JPG

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtX1SsxT0lGyBGITYyBhaGysFKsTrWQGlTACSViAJAwtwBIuiSWpQK4TELsAsSNY0Byq2tAcRBiYGgApc7CMBUzGBEQYmYIUmCjFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, A = _t, B = _t, C = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type text}, {"A", type text}, {"B", type text}, {"C", type text}}),
    #"Demoted Headers" = Table.DemoteHeaders(#"Changed Type"),
    #"Changed Type1" = Table.TransformColumnTypes(#"Demoted Headers",{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type1", "Index", 1, 1),
    #"Added Conditional Column" = Table.AddColumn(#"Added Index", "Custom", each if [Column1] = "Date" then [Index] else null),
    #"Filled Down" = Table.FillDown(#"Added Conditional Column",{"Custom"}),
    #"Removed Columns" = Table.RemoveColumns(#"Filled Down",{"Index"}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Removed Columns", {"Column1", "Custom"}, "Attribute", "Value"),
    #"Sorted Rows" = Table.Sort(#"Unpivoted Columns",{{"Custom", Order.Ascending}, {"Attribute", Order.Ascending}, {"Value", Order.Descending}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Sorted Rows", "Value", "Value - Copy"),
    #"Changed Type2" = Table.TransformColumnTypes(#"Duplicated Column",{{"Value - Copy", type number}}),
    #"Replaced Errors" = Table.ReplaceErrorValues(#"Changed Type2", {{"Value - Copy", 9999}}),
    #"Added Conditional Column1" = Table.AddColumn(#"Replaced Errors", "Custom.1", each if [#"Value - Copy"] = 9999 then [Value] else null),
    #"Filled Down1" = Table.FillDown(#"Added Conditional Column1",{"Custom.1"}),
    #"Filtered Rows" = Table.SelectRows(#"Filled Down1", each [#"Value - Copy"] <> 9999),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Custom", "Attribute", "Value - Copy"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns1",{"Column1", "Custom.1", "Value"}),
    #"Sorted Rows1" = Table.Sort(#"Reordered Columns",{{"Column1", Order.Ascending}, {"Custom.1", Order.Ascending}})
in
    #"Sorted Rows1"

Best Regards
Maggie
Community Support Team _ Maggie 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

4 REPLIES 4
v-juanli-msft
Community Support
Community Support

Hi @PiyushBQ 

Copy and paste my query in advanced editor

Capture6.JPG

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtX1SsxT0lGyBGITYyBhaGysFKsTrWQGlTACSViAJAwtwBIuiSWpQK4TELsAsSNY0Byq2tAcRBiYGgApc7CMBUzGBEQYmYIUmCjFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, A = _t, B = _t, C = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type text}, {"A", type text}, {"B", type text}, {"C", type text}}),
    #"Demoted Headers" = Table.DemoteHeaders(#"Changed Type"),
    #"Changed Type1" = Table.TransformColumnTypes(#"Demoted Headers",{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type1", "Index", 1, 1),
    #"Added Conditional Column" = Table.AddColumn(#"Added Index", "Custom", each if [Column1] = "Date" then [Index] else null),
    #"Filled Down" = Table.FillDown(#"Added Conditional Column",{"Custom"}),
    #"Removed Columns" = Table.RemoveColumns(#"Filled Down",{"Index"}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Removed Columns", {"Column1", "Custom"}, "Attribute", "Value"),
    #"Sorted Rows" = Table.Sort(#"Unpivoted Columns",{{"Custom", Order.Ascending}, {"Attribute", Order.Ascending}, {"Value", Order.Descending}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Sorted Rows", "Value", "Value - Copy"),
    #"Changed Type2" = Table.TransformColumnTypes(#"Duplicated Column",{{"Value - Copy", type number}}),
    #"Replaced Errors" = Table.ReplaceErrorValues(#"Changed Type2", {{"Value - Copy", 9999}}),
    #"Added Conditional Column1" = Table.AddColumn(#"Replaced Errors", "Custom.1", each if [#"Value - Copy"] = 9999 then [Value] else null),
    #"Filled Down1" = Table.FillDown(#"Added Conditional Column1",{"Custom.1"}),
    #"Filtered Rows" = Table.SelectRows(#"Filled Down1", each [#"Value - Copy"] <> 9999),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Custom", "Attribute", "Value - Copy"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns1",{"Column1", "Custom.1", "Value"}),
    #"Sorted Rows1" = Table.Sort(#"Reordered Columns",{{"Column1", Order.Ascending}, {"Custom.1", Order.Ascending}})
in
    #"Sorted Rows1"

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

This is perfect, Maggie.

Thank you so much!

parry2k
Super User
Super User

@PiyushBQ unpivot should work and is the solution. 

 

- transform data
- select date column in the table table
- right-click, unpivot other columns it will add two columns, attribute, and value, rename these as per your requirement
- close and apply

To visual, take table visual, put date, attribute, and value to see the result.

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.






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

Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.





Thanks for taking the time out @parry2k 

Unpivoting is the first thing I tried, and it doesn't work.

Here's the output for you (notice how D gets missed out)

DateAttributeValue

1/5/2020A9
1/5/2020B43
1/5/2020C133
1/6/2020A2
1/6/2020B48
1/6/2020C118
DateAB
DateBD
DateCA
1/7/2020A17
1/7/2020B1050
1/7/2020C7
1/8/2020A14
1/8/2020B1257
1/8/2020C4
   

Helpful resources

Announcements
May 23 2022 epsiode 5 without aka link.jpg

The Power BI Community Show

Welcome to the Power BI Community Show! Jeroen ter Heerdt talks about the importance of Data Modeling.

charticulator_carousel_with_text (1).png

Charticulator Design Challenge

Put your data visualization and design skills to the test! This exciting challenge is happening now through June10th!

Power BI Dev Camp Session 22 without aka link and time 768x460.jpg

Check it Out!

Watch Session 22 Ted's Dev Camp along with past sessions!

Power BI Release May 2022 768x460.png

Check it out!

Click here to read more about the May 2022 updates!

Top Kudoed Authors