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
ERCLOS
Frequent Visitor

Sum the set of records of identical name IDs in first column across time

Hi All, 
Trust you are well!

I am new to this forum and I have searched for similar approaches to the issue below I am facing but could not find it here!

It goes like transforming the first table below into the second table using Power Query or M Languange.

it basically sums all the values or records from second column onwards (time frame) of the name identifiers A, B, C, and so on.

 

Your feedback, suggestion is very much appreciated!

 

FROM THIS
Date01-Jan02-Jan03-Jan04-Jan05-Jan06-Jan07-Jan08-Jan09-Jan10-Jan11-Jan12-Jan13-Jan14-Jan15-Janetc
A111111111111    
A            1111
B      1111111111
B            1111
B111111111111    
C111111111111    
C            1111
C      1111111111
C                
D111111111111    
etc                
TO THIS
Date01-Jan02-Jan03-Jan04-Jan05-Jan06-Jan07-Jan08-Jan09-Jan10-Jan11-Jan12-Jan13-Jan14-Jan15-Janetc
A1111111111112222
B      1111112222
C1111111111111111
D111111111111    
etc                
1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

Unpivot and the re-pivot using sum as the aggregation.

 

Select the Date column and click Unpivot Columns > Unpivot Other Column in the Transform tab:

AlexisOlson_0-1640193290309.png

 

Select the Attribute column and click on Pivot Column. Choose the Value column as the Values Column.

AlexisOlson_1-1640193330117.png

 

Result:

AlexisOlson_2-1640193519177.png

 

Sample M query you can paste into the Advanced Editor:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTKEYgWlWB2IiAIUG4JFnIgUQTXHGasIqi78IhBdLkjmKMXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, #"01-Jan" = _t, #"02-Jan" = _t, etc = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"01-Jan", Int64.Type}, {"02-Jan", Int64.Type}, {"etc", Int64.Type}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Date"}, "Attribute", "Value"),
    #"Pivoted Column" = Table.Pivot(#"Unpivoted Columns", List.Distinct(#"Unpivoted Columns"[Attribute]), "Attribute", "Value", List.Sum)
in
    #"Pivoted Column"

 

View solution in original post

2 REPLIES 2
ERCLOS
Frequent Visitor

That has worked fantastically! thanks

AlexisOlson
Super User
Super User

Unpivot and the re-pivot using sum as the aggregation.

 

Select the Date column and click Unpivot Columns > Unpivot Other Column in the Transform tab:

AlexisOlson_0-1640193290309.png

 

Select the Attribute column and click on Pivot Column. Choose the Value column as the Values Column.

AlexisOlson_1-1640193330117.png

 

Result:

AlexisOlson_2-1640193519177.png

 

Sample M query you can paste into the Advanced Editor:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTKEYgWlWB2IiAIUG4JFnIgUQTXHGasIqi78IhBdLkjmKMXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, #"01-Jan" = _t, #"02-Jan" = _t, etc = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"01-Jan", Int64.Type}, {"02-Jan", Int64.Type}, {"etc", Int64.Type}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Date"}, "Attribute", "Value"),
    #"Pivoted Column" = Table.Pivot(#"Unpivoted Columns", List.Distinct(#"Unpivoted Columns"[Attribute]), "Attribute", "Value", List.Sum)
in
    #"Pivoted Column"

 

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