Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I have a table of sales opportunities, and I want to create a column which displays the ratio of the opportunity's value compared to all active opportunities. I was able to accomplish this with the following column:
RATIO = Data[Amount] / CALCULATE(SUM(Data[Amount]),ALL(Data))
But my next step is to have this ratio be dependent on four slicers I have added: Quarter, Territory, Product Family, Opportunity Stage. When a user selects the 1st Quarter, EMEA Territory, ABC Product Family, Validated Opportunity Status, I want this column to adjust the denominator of the above calucation to only include opportunities which meet these criteria.
Can anyone shed any light on how I could do this? I am new to Power BI, and the filtering functions have not been very intuitive to me. Thank you for any help you can provide.
Solved! Go to Solution.
Hi @kolson256,
According to your description, using ALLSELECTED Function (DAX) should meet your needs. The formula below is for your reference.
RATIO = SUM ( Table1[Amount] ) / CALCULATE ( SUM ( Table1[Amount] ), ALLSELECTED () )
Regards
Hi @kolson256,
The value of a Calculated Column is computed during data refresh and uses the current row as a context; it does not depend on user interaction in the report.
In this scenario, you should create a Measure instead, then show it with the Opportunities on the report. For more details about differences between Calculated Columns and Measures, please refer to this article.
And the formula below to create the measure is for your reference.
RATIO = SUM ( Data[Amount] ) / CALCULATE ( SUM ( Data[Amount] ), ALLEXCEPT ( Data, Data[Quarter], Data[Territory], Data[Product Family], Data[Opportunity Stage] ) )
Regards
Is it possible to add additional filter to this formula which can filter the above data for TOPN customers also. I want it done dynamically.Cannot use the visual filter.
Thank you everyone, using ALLEXCEPT does seem to have put me on the right track.
@v-ljerr-msft, the problem I still run into using your formula is it always calculates the ratio for each opportunity based on other opportunities which share all 4 attributes (Quarter, Territory, Product Family, Opportunity Stage). What I would like to have in the denominator is every opportunity which matches the user's current selections in the slicers.
For instance, if the user has selected 1st Quarter, EMEA Territory, ABC Family, then my table will show all opportunities of all stages. I would like the ratio to then show the Amount / SUM(All Opportunities currently displayed in the table). For instance I would like the table to look like Table 1 if I haven't made a selection in the Opportunity Stage slicer, but look like Table 2 if I have selected the Identify Stage.
Table 1
Quarter | Territory | Family | Stage | Amount | Ratio |
1 | EMEA | ABC | Identify | 100 | 10% |
1 | EMEA | ABC | Identify | 500 | 50% |
1 | EMEA | ABC | Closed / Won | 400 | 40% |
Total | 1000 | 100% |
Table 2
Quarter | Territory | Family | Stage | Amount | Ratio |
1 | EMEA | ABC | Identify | 100 | 17% |
1 | EMEA | ABC | Identify | 500 | 83% |
Total | 600 | 100% |
Hi @kolson256,
According to your description, using ALLSELECTED Function (DAX) should meet your needs. The formula below is for your reference.
RATIO = SUM ( Table1[Amount] ) / CALCULATE ( SUM ( Table1[Amount] ), ALLSELECTED () )
Regards
@v-ljerr-msft Thank you, that did indeed do the trick. I had gotten it to work with ALLSELECTED shortly after my last post by taking the advice from @Baskar to read into ALL, ALLEXCEPT, and ALLSELECTED, and both of your comments were very helpful. I have accepted your most recent answer as it did fully resolve the issue.
Thanks again.
In this case ALLEXCEPT will help u.
u have to understand the difference between ALL, ALLSELECTED, ALLEXCEPT.
your calculation is almost correct dude, have one simple correction .
u have to add ALLEXCEPT and apply what every column u want.
thats it.
cool
Hi @kolson256,
as @parry2k correctly said, ALLEXCEPT function will do what you want.
Just use modified formula:
RATIO = Data[Amount] / CALCULATE(SUM(Data[Amount]),ALLEXCEPT(Data;Data[Quarter];Data[Territory];Data[Product Family];Data[Opportunity]))
Regards.
Pavel
You should be able to achieve this by using ALLEXCEPT function
here is more information https://msdn.microsoft.com/en-us/library/ee634795.aspx
Let me know if need further help with the formula. Thanks!
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.
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
115 | |
107 | |
101 | |
38 | |
35 |
User | Count |
---|---|
149 | |
122 | |
76 | |
74 | |
52 |