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
t_guet01
Helper I
Helper I

How do I calculate a custom column based on filtered rows?

Hey guys,

 

I am currently trying to calculate the revenue per country based on some kind of universal list price for the sake of comparability. I am facing transaction data per continent ("North America", "Rest"), per country, and per productID.

 

I want to add a custom column ideally in Power Query (but DAX is also possible), which states the average list price for the productID but only takes list prices of the continent "Rest" into account.

 

t_guet01_0-1621237111314.png

Some examples:

  • ProductID 123: Is sold in 3 transaction lines. 2 transaction lines are sold from continent "Rest" and are taken into account for the calculation. The average price is 12,50 € (13 € to Germany and 12 € to USA) --> all 3 transaction lines receive the average list price of 12,5 € (see column "SolutionPrice")
  • Product 456: sold in 2 transcation lines solely from continent "Rest". Average is 80 €. 
  • exception: Product 980: only sold from continent "North America" --> in this case the list price should be calculated based on the values from North America, so 54 € on average (55 € and 53 €).


I added a column "SolutionPrice" to the data model to give you an idea of the desired values. I calculated this column in Excel. My original data model is massive and I would like to do the calculation in Power BI, not Excel.
A sample data set can be found here: https://www.dropbox.com/sh/xfprg05oks3g3zy/AACRd4NsuoW1Exh0uz2xNOnGa?dl=0

 

Thank you in advance.


Best

Tom

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi, @t_guet01 

Please check the below picture and the sample pbix file's link down below.

It is for creating a new column.

 

Picture9.png

 

Solution Price CC =
VAR currentproductid = Transactions[ProductID]
VAR newtableorigin =
SUMMARIZE (
FILTER ( Transactions, Transactions[ProductID] = currentproductid ),
Transactions[ContinentOfOrigin]
)
VAR newtable =
SUMMARIZE (
FILTER ( Transactions, Transactions[ProductID] = currentproductid ),
Transactions[ContinentOfOrigin],
Transactions[Price]
)
VAR tablerest =
SUMMARIZE (
FILTER (
Transactions,
Transactions[ProductID] = currentproductid
&& Transactions[ContinentOfOrigin] = "Rest"
),
Transactions[ContinentOfOrigin],
Transactions[Price]
)
RETURN
SWITCH (
TRUE (),
"Rest" IN newtableorigin, AVERAGEX ( tablerest, Transactions[Price] ),
AVERAGEX ( newtable, Transactions[Price] )
)
 
 
 

Hi, My name is Jihwan Kim.


If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.


Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

3 REPLIES 3
Jihwan_Kim
Super User
Super User

Hi, @t_guet01 

Please check the below picture and the sample pbix file's link down below.

It is for creating a new column.

 

Picture9.png

 

Solution Price CC =
VAR currentproductid = Transactions[ProductID]
VAR newtableorigin =
SUMMARIZE (
FILTER ( Transactions, Transactions[ProductID] = currentproductid ),
Transactions[ContinentOfOrigin]
)
VAR newtable =
SUMMARIZE (
FILTER ( Transactions, Transactions[ProductID] = currentproductid ),
Transactions[ContinentOfOrigin],
Transactions[Price]
)
VAR tablerest =
SUMMARIZE (
FILTER (
Transactions,
Transactions[ProductID] = currentproductid
&& Transactions[ContinentOfOrigin] = "Rest"
),
Transactions[ContinentOfOrigin],
Transactions[Price]
)
RETURN
SWITCH (
TRUE (),
"Rest" IN newtableorigin, AVERAGEX ( tablerest, Transactions[Price] ),
AVERAGEX ( newtable, Transactions[Price] )
)
 
 
 

Hi, My name is Jihwan Kim.


If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.


Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Hi Jihwan Kim,

perfect, thanks a lot!

just out of interest: do you know the respective functions in Power Query? So the equivalents for "summarize" etc.?

Hi, @t_guet01 

Thank you for your feedback.

I think the function Groupby function in Power Query Editor is similar to the Summarize function in DAX.

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


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.