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

Adding/Merging of Rows with Summation of values in Power Query Editor

Hello Fabric Community, @Fabrico  @Sermicro  @fabricos 

 

I have a input table like shown below.

 

CountryFieldValue
JapanC1-Onroad2346
JapanC1-Offroad4573
JapanC1-Junction2345
JapanC1-Signal4678
JapanC2-Onroad9087
JapanC2-Offroad7890
JapanC2-Junction7658
JapanC2-Signal4567
NepalC1-Onroad3456
NepalC1-Offroad4267
NepalC1-Junction2311
NepalC1-Signal4566
NepalC2-Onroad3213
NepalC2-Offroad3477
NepalC2-Junction1355
NepalC2-Signal3288

 

 

I required output like the below mentioned table.

CountryFieldValue
JapanC1-Onroad2346
JapanC1-Offroad4573
JapanC1-Junction2345
JapanC1-Signal4678
JapanC2-Onroad9087
JapanC2-Offroad7890
JapanC2-Junction7658
JapanC2-Signal4567
NepalC114600
NepalC211333

 

I want to this excersie in Power Query. Please help me. 

Thanks in advance.
@PowerQuairy  @MrPowerQuery  @powerquerytony1 
@

1 ACCEPTED SOLUTION
tackytechtom
Super User
Super User

Hi @suparnababu8 ,

 

How about this?

tackytechtom_0-1705920608936.png

 

 

Not sure though, why you wanna do the grouping solely by Nepal and not Japan, but check out the solution below that you can paste into the advanced editor (if you do not know, how to exactly do this, please check out this quick walkthrough)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZZA9D8IgFEX/C3NNCo/Ho7NbBx0cmw5ErWliaNPo/xet4eOxEU7uPVyGQfRudV404igPZ78t7hbOCrQRY1PCafpTjQSc9m9/fc2L38PI8WV+ePf8Zg3ZEqqk7VpLFYxasl3LaaYlg1Vz0qLZm0/39XeRrw3vNRVMa1UdLdZKyXGuZc3ZWlASKhi1oIk4zbQSEDmOWlA2fMX4AQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Field = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"Field", type text}, {"Value", Int64.Type}}),
    #"Filtered Rows 1" = Table.SelectRows(#"Changed Type", each ([Country] = "Japan")),
    #"Filtered Rows 2" = Table.SelectRows(#"Changed Type", each ([Country] = "Nepal")),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Filtered Rows 2", "Field", Splitter.SplitTextByDelimiter("-", QuoteStyle.None), {"Field", "Field.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Field", type text}, {"Field.2", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type1", {"Country", "Field"}, {{"Value", each List.Sum([Value]), type nullable number}}),
    #"Appended Query" = Table.Combine({#"Filtered Rows 1", #"Grouped Rows"})
in
    #"Appended Query"

 

Please, let me know if this helps 🙂

 

/Tom
https://www.tackytech.blog/
https://www.instagram.com/tackytechtom/



Did I answer your question➡️ Please, mark my post as a solution ✔️

Also happily accepting Kudos 🙂

Feel free to connect with me on LinkedIn! linkedIn

#proudtobeasuperuser 

View solution in original post

2 REPLIES 2
tackytechtom
Super User
Super User

Hi @suparnababu8 ,

 

How about this?

tackytechtom_0-1705920608936.png

 

 

Not sure though, why you wanna do the grouping solely by Nepal and not Japan, but check out the solution below that you can paste into the advanced editor (if you do not know, how to exactly do this, please check out this quick walkthrough)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZZA9D8IgFEX/C3NNCo/Ho7NbBx0cmw5ErWliaNPo/xet4eOxEU7uPVyGQfRudV404igPZ78t7hbOCrQRY1PCafpTjQSc9m9/fc2L38PI8WV+ePf8Zg3ZEqqk7VpLFYxasl3LaaYlg1Vz0qLZm0/39XeRrw3vNRVMa1UdLdZKyXGuZc3ZWlASKhi1oIk4zbQSEDmOWlA2fMX4AQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Field = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"Field", type text}, {"Value", Int64.Type}}),
    #"Filtered Rows 1" = Table.SelectRows(#"Changed Type", each ([Country] = "Japan")),
    #"Filtered Rows 2" = Table.SelectRows(#"Changed Type", each ([Country] = "Nepal")),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Filtered Rows 2", "Field", Splitter.SplitTextByDelimiter("-", QuoteStyle.None), {"Field", "Field.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Field", type text}, {"Field.2", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type1", {"Country", "Field"}, {{"Value", each List.Sum([Value]), type nullable number}}),
    #"Appended Query" = Table.Combine({#"Filtered Rows 1", #"Grouped Rows"})
in
    #"Appended Query"

 

Please, let me know if this helps 🙂

 

/Tom
https://www.tackytech.blog/
https://www.instagram.com/tackytechtom/



Did I answer your question➡️ Please, mark my post as a solution ✔️

Also happily accepting Kudos 🙂

Feel free to connect with me on LinkedIn! linkedIn

#proudtobeasuperuser 

Thanks a lot @tackytechtom  🙂. It's worked.👍

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