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
lcy0328
New Member

How to unstack a column into table using referncing index + pivot the table

Hi, community,

 

I'm facing a problem to unstack this copied & pasted info in a column and make it into a table.

 

I found the rows of info sets are not consistent (some have 4 rows, some 5 rows) and not able to use Mordulo function. So I tried to add another column and identify the "null" row with index "0" and would like to fill the consequence number then Pivot table, then everything should be fine. But do not know how to fill down the numbers. 😥

 

Capturepbi-edited.PNG

Please let me know whether my toughts are correct and could work. If so, how to finish the rest steps. If not, please suggest if any other good solutions. 

Thank you. 

 

PS: Sorry that I can not enclose this data file as with confidentiality problem. 

2 ACCEPTED SOLUTIONS
AlB
Super User
Super User

Hi @lcy0328

Place the following M code in a blank query to see the steps:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WUorViVbyMYRQRhDKGEKZQChTMAVVB1MIpY2htIkhiiK4KrgyuDo0hQiVCKUItVCWKZgVCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Col1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Col1", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"Col1"}),
    list0_ = #"Replaced Value"[Col1],
    list1_ = if List.Last(list0_)<>null then list0_&{null} else list0_ = null, //Make sure list finishes with a null to make things easier in the next step   
    list2_ = if List.First(list1_)=null then List.LastN(list1_,List.Count(list1_)-1) else list1_,
    list3_ = List.Accumulate(list2_,[total={}, partial={}],(s,c)=> if c<>null then [total=s[total], partial=s[partial]&{c}] else [total=s[total]&{s[partial]}, partial={}]),
    total = list3_[total],
    #"Converted to Table" = Table.FromList(total, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Added Custom" = Table.AddColumn(#"Converted to Table", "Custom", each Text.Combine([Column1],"|")),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Added Custom", "Custom", Splitter.SplitTextByDelimiter("|", QuoteStyle.Csv), {"Line1", "Line2", "Line3", "Line4", "Line5"}),
    #"Removed Columns" = Table.RemoveColumns(#"Split Column by Delimiter",{"Column1"})
in
    #"Removed Columns"

 

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

View solution in original post

Jimmy801
Community Champion
Community Champion

Hello @lcy0328 

 

try this approach. Uses Table.Group to split your tables on every "null", then skip and transpose every single column.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WUorViVbyMYRQRhDKGEKZQChTMAVVB1MIpY2htIkhiiK4KrgyuDo0hQiVCKUItVCWKZgVCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Col1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Col1", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"Col1"}),
    #"Grouped Rows" = Table.Group(#"Replaced Value", {"Col1"}, {{"AllRows", each Table.Transpose(Table.Skip(_,1)), type table [Col1=text]}}, GroupKind.Local,   (g,c)=> if c[Col1]=null then 1 else 0),
    #"Removed Other Columns" = Table.SelectColumns(#"Grouped Rows",{"AllRows"}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Removed Other Columns", "AllRows", {"Column1","Column2","Column3","Column4","Column5"})
in
    #"Expanded AllRows"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

3 REPLIES 3
Jimmy801
Community Champion
Community Champion

Hello @lcy0328 

 

try this approach. Uses Table.Group to split your tables on every "null", then skip and transpose every single column.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WUorViVbyMYRQRhDKGEKZQChTMAVVB1MIpY2htIkhiiK4KrgyuDo0hQiVCKUItVCWKZgVCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Col1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Col1", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"Col1"}),
    #"Grouped Rows" = Table.Group(#"Replaced Value", {"Col1"}, {{"AllRows", each Table.Transpose(Table.Skip(_,1)), type table [Col1=text]}}, GroupKind.Local,   (g,c)=> if c[Col1]=null then 1 else 0),
    #"Removed Other Columns" = Table.SelectColumns(#"Grouped Rows",{"AllRows"}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Removed Other Columns", "AllRows", {"Column1","Column2","Column3","Column4","Column5"})
in
    #"Expanded AllRows"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

AlB
Super User
Super User

Hi @lcy0328

Place the following M code in a blank query to see the steps:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WUorViVbyMYRQRhDKGEKZQChTMAVVB1MIpY2htIkhiiK4KrgyuDo0hQiVCKUItVCWKZgVCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Col1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Col1", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"Col1"}),
    list0_ = #"Replaced Value"[Col1],
    list1_ = if List.Last(list0_)<>null then list0_&{null} else list0_ = null, //Make sure list finishes with a null to make things easier in the next step   
    list2_ = if List.First(list1_)=null then List.LastN(list1_,List.Count(list1_)-1) else list1_,
    list3_ = List.Accumulate(list2_,[total={}, partial={}],(s,c)=> if c<>null then [total=s[total], partial=s[partial]&{c}] else [total=s[total]&{s[partial]}, partial={}]),
    total = list3_[total],
    #"Converted to Table" = Table.FromList(total, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Added Custom" = Table.AddColumn(#"Converted to Table", "Custom", each Text.Combine([Column1],"|")),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Added Custom", "Custom", Splitter.SplitTextByDelimiter("|", QuoteStyle.Csv), {"Line1", "Line2", "Line3", "Line4", "Line5"}),
    #"Removed Columns" = Table.RemoveColumns(#"Split Column by Delimiter",{"Column1"})
in
    #"Removed Columns"

 

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

wdx223_Daniel
Super User
Super User

@lcy0328 try put this code in the step next to the Source.

=Table.Comine(Table.Group(Source,"Column1",{"n",each Table.FromRows({List.Skip([Column1])})},0,(x,y)=>Byte.From(y=null))[n])

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.

Top Solution Authors
Top Kudoed Authors