Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello Fabric Community, @Fabrico @Sermicro @fabricos
I have a input table like shown below.
Country | Field | Value |
Japan | C1-Onroad | 2346 |
Japan | C1-Offroad | 4573 |
Japan | C1-Junction | 2345 |
Japan | C1-Signal | 4678 |
Japan | C2-Onroad | 9087 |
Japan | C2-Offroad | 7890 |
Japan | C2-Junction | 7658 |
Japan | C2-Signal | 4567 |
Nepal | C1-Onroad | 3456 |
Nepal | C1-Offroad | 4267 |
Nepal | C1-Junction | 2311 |
Nepal | C1-Signal | 4566 |
Nepal | C2-Onroad | 3213 |
Nepal | C2-Offroad | 3477 |
Nepal | C2-Junction | 1355 |
Nepal | C2-Signal | 3288 |
I required output like the below mentioned table.
Country | Field | Value |
Japan | C1-Onroad | 2346 |
Japan | C1-Offroad | 4573 |
Japan | C1-Junction | 2345 |
Japan | C1-Signal | 4678 |
Japan | C2-Onroad | 9087 |
Japan | C2-Offroad | 7890 |
Japan | C2-Junction | 7658 |
Japan | C2-Signal | 4567 |
Nepal | C1 | 14600 |
Nepal | C2 | 11333 |
I want to this excersie in Power Query. Please help me.
Thanks in advance.
@PowerQuairy @Anonymous @powerquerytony1
@
Solved! Go to Solution.
Hi @suparnababu8 ,
How about this?
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! | |
#proudtobeasuperuser | |
Hi @suparnababu8 ,
How about this?
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! | |
#proudtobeasuperuser | |