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
hackfifi
Helper V
Helper V

Duplicating Rows based on Value in Column

Hi All - I need support via Power Query to transfrom my data as below:

Essentially Duplicated the Rows, and convert the "count" to 1

 

Also, data table is added below the screenshot.

 

Cheers!!

 

 

Duplicate Rows.PNG

 

TypeJan-20Feb-20Mar-20Apr-20
A1122
B2221
C1133
1 ACCEPTED SOLUTION
dax
Community Support
Community Support

Hi @hackfifi , 

You could try below M code 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTKEYiMwjtWJVnKC8yDYECzqjKTWGIxjYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Type = _t, #"Jan-20" = _t, #"Feb-20" = _t, #"Mar-20" = _t, #"Apr-20" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}, {"Jan-20", Int64.Type}, {"Feb-20", Int64.Type}, {"Mar-20", Int64.Type}, {"Apr-20", Int64.Type}}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Type"}, "Attribute", "Value"),
    #"Added Custom1" = Table.AddColumn(#"Unpivoted Columns", "Custom", each {Number.From(1)..Number.From([Value])}),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom1", "Custom"),
    #"Pivoted Column" = Table.Pivot(#"Expanded Custom", List.Distinct(#"Expanded Custom"[Attribute]), "Attribute", "Value", List.Count),
    #"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Custom"}),
    #"Replaced Value" = Table.ReplaceValue(#"Removed Columns",0,null,Replacer.ReplaceValue,{"Jan-20", "Feb-20", "Mar-20", "Apr-20"})
in
    #"Replaced Value"

Best Regards,
Zoe Zhi

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

5 REPLIES 5
collinq
Super User
Super User

Hi @hackfifi ,,

 

I think that this will get you there and then you can change the value to "1" from "2" or "3".

 

https://community.powerbi.com/t5/Desktop/Create-Duplicate-Entries-based-on-Column-Value/td-p/359228

 

I would appreciate Kudos if my response was helpful. I would also appreciate it if you would Mark this As a Solution if it solved the problem. Thanks!



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

Proud to be a Datanaut!
Private message me for consulting or training needs.




@collinq thanks mate - but that doesnt work as i need to do this in the POWER QUERY, and the complication is my "count" is across columns (i.e. by month)

I tried unpivoting the data and doing it; but no luck.

 

Appreciate your response.

dax
Community Support
Community Support

Hi @hackfifi , 

You could try below M code 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTKEYiMwjtWJVnKC8yDYECzqjKTWGIxjYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Type = _t, #"Jan-20" = _t, #"Feb-20" = _t, #"Mar-20" = _t, #"Apr-20" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}, {"Jan-20", Int64.Type}, {"Feb-20", Int64.Type}, {"Mar-20", Int64.Type}, {"Apr-20", Int64.Type}}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Type"}, "Attribute", "Value"),
    #"Added Custom1" = Table.AddColumn(#"Unpivoted Columns", "Custom", each {Number.From(1)..Number.From([Value])}),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom1", "Custom"),
    #"Pivoted Column" = Table.Pivot(#"Expanded Custom", List.Distinct(#"Expanded Custom"[Attribute]), "Attribute", "Value", List.Count),
    #"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Custom"}),
    #"Replaced Value" = Table.ReplaceValue(#"Removed Columns",0,null,Replacer.ReplaceValue,{"Jan-20", "Feb-20", "Mar-20", "Apr-20"})
in
    #"Replaced Value"

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thanks @dax - that worked!

@collinq - thanks for your support again!

Hi @hackfifi ,

 

I have run out of time but I ALMOST have it.  Since I won't get back to this for about 4 days I am giving what I have right now.  I did an unpivot and a pivot and I get this result:

Type20-Jan20-Feb20-Mar20-Apr 
A1100 
A0011 
B0001 
B1110 
C1100 
C0011 
      

 

 

What is missing is the expected third row of "C".  I am wondering if we put a "count" or an index field or something that we can add to the pivot?  Let me know how it goes, I will check back next week when I can.

 

I built my own data table to match your original (or so I think) so my source and yours will differ....

 

Here is the code I used to get there:

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTKEYiMwjtWJVnKC8yDYECzqjKTWGIxjYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Type = _t, #"Jan-20" = _t, #"Feb-20" = _t, #"Mar-20" = _t, #"Apr-20" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}, {"Jan-20", Int64.Type}, {"Feb-20", Int64.Type}, {"Mar-20", Int64.Type}, {"Apr-20", Int64.Type}}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Type"}, "Attribute", "Value"),
#"Renamed Columns" = Table.RenameColumns(#"Unpivoted Columns",{{"Attribute", "Month"}}),
#"Added Custom" = Table.AddColumn(#"Renamed Columns", "GiveMea1", each 1),
#"Changed Type1" = Table.TransformColumnTypes(#"Added Custom",{{"GiveMea1", type text}}),
#"Pivoted Column" = Table.Pivot(#"Changed Type1", List.Distinct(#"Changed Type1"[Month]), "Month", "GiveMea1", List.Count),
#"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Value"})
in
#"Removed Columns"

 

 

I would appreciate Kudos if my response was helpful. I would also appreciate it if you would Mark this As a Solution if it solved the problem. Thanks!



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

Proud to be a Datanaut!
Private message me for consulting or training needs.




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.