Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Lecram36
Regular Visitor

Variable line by line computation based on value in second table

Hi 

Need some help here ... Tryitng to compute a "Currency Impact". Given a "base" table with, say, sales in local currency, and an exchange rate; given a "fxrate" table that is sliced to filter to a unique reference, how can I compute line-by-line and get the total ? The formula needs to be efficient, because there are easily 500'000 rows in "base". Not easy to explain the issue, so I made a little drawing! Any help is higly appreciated ...

 

Capture.JPG

1 ACCEPTED SOLUTION
v-lili6-msft
Community Support
Community Support

HI @Lecram36 

First, you should know that:

1. Calculation column/table not support dynamic changed based on filter or slicer.
2. Measure can be affected by filter/slicer, so you can use it to get dynamic summary result in a visual.

https://www.sqlbi.com/articles/calculated-columns-and-measures-in-dax/

 

Second, for your case, you could try this way as below:

Step1:

Create a relationalship between Datatable and FXTable by Currency column.(This relationship will be many to many)

Step2:

Then create a measure as below:

 

Impact = 
SUMX('Data Table', CALCULATE(SUM('Data Table'[Sales])-SUM('Data Table'[Sales])*DIVIDE(SUM('Data Table'[FxRate]),SUM(FXTable[RefFxRate]))))

 

 

Result:

5.JPG

and here is sample pbix file, please try it.

 

Regards,

Lin

Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-lili6-msft
Community Support
Community Support

HI @Lecram36 

First, you should know that:

1. Calculation column/table not support dynamic changed based on filter or slicer.
2. Measure can be affected by filter/slicer, so you can use it to get dynamic summary result in a visual.

https://www.sqlbi.com/articles/calculated-columns-and-measures-in-dax/

 

Second, for your case, you could try this way as below:

Step1:

Create a relationalship between Datatable and FXTable by Currency column.(This relationship will be many to many)

Step2:

Then create a measure as below:

 

Impact = 
SUMX('Data Table', CALCULATE(SUM('Data Table'[Sales])-SUM('Data Table'[Sales])*DIVIDE(SUM('Data Table'[FxRate]),SUM(FXTable[RefFxRate]))))

 

 

Result:

5.JPG

and here is sample pbix file, please try it.

 

Regards,

Lin

Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
parry2k
Super User
Super User

@Lecram36 Based on your data table, it should be something like this, add as a column

 

Sales Impact = 
Table[Sales] - ( DIVIDE ( ( Table[Sales] * Table[FxRate] ), Table[RefFxRate] ) )

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

@parry2k  Nope, unfortunately not that simple: Table[RefFxRate] is not available. It's in the excel sheet for the demo of the calculation, but it's an external value computed 'on the fly'

 

@Lecram36 

ok then you have to share your data the way it look and the model/relationship diagram.

 


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.