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

Find % of Total

Here is my data columns, i need to find the % for each individual, (so for each name total the amount then take individual values and divide by total) but I need the Name column and the Ordered2023 column..

 

i am trying to figure how to add a total column for each name but cant figure it out, any suggestions?

 

mts_0-1685461322564.png

 

currently i have a second duplicate table, groupby name that gives me the total, i merge the total to original data table above, then do the division.... wondering if there is another more efficient way to do it without the need to add a table to get totals.

 

thanks

1 ACCEPTED SOLUTION
slorin
Super User
Super User

Hi,

A solution with Group and Expand. 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTJUitWBsIzALCcgyxTOsoCzLMEsZ7gOZ7gOEMtEKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Names = _t, Count = _t]),
Type = Table.TransformColumnTypes(Source,{{"Count", type number}}),
Group = Table.Group(Type, {"Names"}, {{"Sum", each List.Sum([Count])}, {"Count", each [Count]}}),
Expand = Table.ExpandListColumn(Group, "Count"),
Percentage = Table.AddColumn(Expand, "%", each [Count] / [Sum], Percentage.Type)
in
Percentage

or with ExpandTableColumn

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTJUitWBsIzALCcgyxTOsoCzLMEsZ7gOZ7gOEMtEKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Names = _t, Count = _t]),
Type = Table.TransformColumnTypes(Source,{{"Count", type number}}),
Group = Table.Group(Type, {"Names"}, {{"Sum", each List.Sum([Count])}, {"Data", each _}}),
Expand = Table.ExpandTableColumn(Group, "Data", {"Count"}, {"Count"}),
Percentage = Table.AddColumn(Expand, "%", each [Count] / [Sum], Percentage.Type)
in
Percentage

Stéphane 

View solution in original post

2 REPLIES 2
slorin
Super User
Super User

Hi,

A solution with Group and Expand. 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTJUitWBsIzALCcgyxTOsoCzLMEsZ7gOZ7gOEMtEKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Names = _t, Count = _t]),
Type = Table.TransformColumnTypes(Source,{{"Count", type number}}),
Group = Table.Group(Type, {"Names"}, {{"Sum", each List.Sum([Count])}, {"Count", each [Count]}}),
Expand = Table.ExpandListColumn(Group, "Count"),
Percentage = Table.AddColumn(Expand, "%", each [Count] / [Sum], Percentage.Type)
in
Percentage

or with ExpandTableColumn

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTJUitWBsIzALCcgyxTOsoCzLMEsZ7gOZ7gOEMtEKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Names = _t, Count = _t]),
Type = Table.TransformColumnTypes(Source,{{"Count", type number}}),
Group = Table.Group(Type, {"Names"}, {{"Sum", each List.Sum([Count])}, {"Data", each _}}),
Expand = Table.ExpandTableColumn(Group, "Data", {"Count"}, {"Count"}),
Percentage = Table.AddColumn(Expand, "%", each [Count] / [Sum], Percentage.Type)
in
Percentage

Stéphane 

edhans
Super User
Super User

You can do it in the same query by creating a 2nd table of the group by, but you will still need to merge.

 

I would step back and ask why are you doing this in Power Query. Getting % of total is usually best done in the DAX side which is optimized for those types of operations. Power Query isn't. Even if you get it to work, and you definitely can, the larger the dataset the slower it becomes until Power Query won't be able to finish. 

Power Query is horrible at table scans, and not great at analysis in general. It is best suited for transforming data so the Power BI model can best analyze it with DAX.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

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