Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more
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!!
| Type | Jan-20 | Feb-20 | Mar-20 | Apr-20 |
| A | 1 | 1 | 2 | 2 |
| B | 2 | 2 | 2 | 1 |
| C | 1 | 1 | 3 | 3 |
Solved! Go to Solution.
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.
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
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.
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.
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:
| Type | 20-Jan | 20-Feb | 20-Mar | 20-Apr | |
| A | 1 | 1 | 0 | 0 | |
| A | 0 | 0 | 1 | 1 | |
| B | 0 | 0 | 0 | 1 | |
| B | 1 | 1 | 1 | 0 | |
| C | 1 | 1 | 0 | 0 | |
| C | 0 | 0 | 1 | 1 | |
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"
Proud to be a Datanaut!
Private message me for consulting or training needs.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.