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
phoenix20
New Member

Column creation - Ratio to sum by group

Hello all

I am struggling quite a lot with the following case. What I want to achieve is to create a column (important) per row that calculates the ratio of a value of that row, to the total by a group. Below is an example with excel with the formula:

 

Example

 

So, the highlighted column is what I want. For example row 2 , the 11,8 is calculated as a the value (B2) to the sum of the cars . The reason I need a column is that I want to use these weights later for creating another column.

 

When I create the following formula alone in Power BI to get totals per group, it works fine:

 

 

Sum_per_group = CALCULATE(SUM(RawData[Sales),RawData[Type]=RawData[Type])

 

If i then enter the value , so to find the ratio , as per below, I get only "Nan" ! (I added only the [Sales]/  )

Ratio = [Sales] /  CALCULATE(SUM(RawData[Sales),RawData[Type]=RawData[Type])

 

 

 

What am I doing wrong? 😕

1 ACCEPTED SOLUTION
Eric_Zhang
Employee
Employee


@phoenix20 wrote:

Hello all

I am struggling quite a lot with the following case. What I want to achieve is to create a column (important) per row that calculates the ratio of a value of that row, to the total by a group. Below is an example with excel with the formula:

 

Example

 

So, the highlighted column is what I want. For example row 2 , the 11,8 is calculated as a the value (B2) to the sum of the cars . The reason I need a column is that I want to use these weights later for creating another column.

 

When I create the following formula alone in Power BI to get totals per group, it works fine:

 

 

Sum_per_group = CALCULATE(SUM(RawData[Sales),RawData[Type]=RawData[Type])

 

If i then enter the value , so to find the ratio , as per below, I get only "Nan" ! (I added only the [Sales]/  )

Ratio = [Sales] /  CALCULATE(SUM(RawData[Sales),RawData[Type]=RawData[Type])

 

 

 

What am I doing wrong? 😕


@phoenix20

You can try to create a calculated column as below. See attached pbix file.

Ratio To Type =
RawData[Sales]
    / CALCULATE ( SUM ( RawData[Sales] ), ALLEXCEPT ( RawData, RawData[Type] ) )

Capture.PNG

View solution in original post

3 REPLIES 3
Eric_Zhang
Employee
Employee


@phoenix20 wrote:

Hello all

I am struggling quite a lot with the following case. What I want to achieve is to create a column (important) per row that calculates the ratio of a value of that row, to the total by a group. Below is an example with excel with the formula:

 

Example

 

So, the highlighted column is what I want. For example row 2 , the 11,8 is calculated as a the value (B2) to the sum of the cars . The reason I need a column is that I want to use these weights later for creating another column.

 

When I create the following formula alone in Power BI to get totals per group, it works fine:

 

 

Sum_per_group = CALCULATE(SUM(RawData[Sales),RawData[Type]=RawData[Type])

 

If i then enter the value , so to find the ratio , as per below, I get only "Nan" ! (I added only the [Sales]/  )

Ratio = [Sales] /  CALCULATE(SUM(RawData[Sales),RawData[Type]=RawData[Type])

 

 

 

What am I doing wrong? 😕


@phoenix20

You can try to create a calculated column as below. See attached pbix file.

Ratio To Type =
RawData[Sales]
    / CALCULATE ( SUM ( RawData[Sales] ), ALLEXCEPT ( RawData, RawData[Type] ) )

Capture.PNG

Ashish_Mathur
Super User
Super User

Hi @phoenix20,

 

Try this clculated column formula

 

=SUM(Data[Sales])/CALCULATE(SUM(Data[Sales]),FILTER(Data,Data[Type]=EARLIER(Data[Type])))

 

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
davehus
Memorable Member
Memorable Member

Hi @phoenix20,

 

Try:

 

SalesbyGroup = CALCULATE(SUM('Table'[sales]),ALLEXCEPT('Table', 'Table'[Type]))

 

Ratio = DIVIDE([Total Sales],[SalesbyGroup])

 

This should give you the desired outcome.

 

Rgds,

 

Dave

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.