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

Calculated Column/Measure based on Filter

Hi, 

 

I needed to create a measure/column that can take a field in opportunity object from SalesForce and multiply based on a filter slicer. For example, I need to multiply opportunity services amount by Booked% below based on the filter if I select commodities and 2/5/2021. Is it possible?

powerbiwork_1-1614710865666.png powerbiwork_0-1614708251655.png

 

Thank you so much in advance. 

 

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

Hi, @powerbiwork 

The filters works on the table visual, so there is no need to create an additional virtual table "myFilteredTable" in your measure "Division Factor".

 

It is recommended to calculate in two steps.
Step1: calculate the factor as below first.

Factor =
SWITCH (
    SELECTEDVALUE ( Opportunity[Commit_Upside__c] ),
    "Booked", SUM ( '2021 Assumptions'[Booked%] ),
    "Commit", SUM ( '2021 Assumptions'[Commit%] ),
    "Upside", SUM ( '2021 Assumptions'[Upside%] ),
    "Potential", SUM ( '2021 Assumptions'[Potebtial%] ),
    "Pipeline", SUM ( '2021 Assumptions'[Pipeline%] )
)

Step 2: Column "Opportunity'[Positive_Services_Amount__c USD])"  multiplied by factor “Factor”

 

Value = SUM(Opportunity[ToUSD-Positive_Services_Amount])* [Division Factor]

 

19.png

 

 

Please check my sample file for more details.

 

Best Regards,
Community Support Team _ Eason
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

5 REPLIES 5
v-easonf-msft
Community Support
Community Support

Hi, @powerbiwork 

The filters works on the table visual, so there is no need to create an additional virtual table "myFilteredTable" in your measure "Division Factor".

 

It is recommended to calculate in two steps.
Step1: calculate the factor as below first.

Factor =
SWITCH (
    SELECTEDVALUE ( Opportunity[Commit_Upside__c] ),
    "Booked", SUM ( '2021 Assumptions'[Booked%] ),
    "Commit", SUM ( '2021 Assumptions'[Commit%] ),
    "Upside", SUM ( '2021 Assumptions'[Upside%] ),
    "Potential", SUM ( '2021 Assumptions'[Potebtial%] ),
    "Pipeline", SUM ( '2021 Assumptions'[Pipeline%] )
)

Step 2: Column "Opportunity'[Positive_Services_Amount__c USD])"  multiplied by factor “Factor”

 

Value = SUM(Opportunity[ToUSD-Positive_Services_Amount])* [Division Factor]

 

19.png

 

 

Please check my sample file for more details.

 

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

 

selimovd
Super User
Super User

Hey @powerbiwork ,

 

you should do that with a measure. A calculated column is always static, so you can't change that dynamically.

Try the following measure and replace your columns accordingly:

 

 

Division Factor =
VAR SelectedDivision = SELECTEDVALUE( DimDivision[Division] )
VAR SelectedDate     = SELECTEDVALUE( DimDate[Date] )
VAR myFilteredTable  =
    CALCULATETABLE(
        MyFactTable,
        DimDate[Date] = SelectedDate,
        DimDivision[Division] = SelectedDivision
    )
RETURN
    SUMX( myFilteredTable, MyFactTable[Booked%] * [Opportunity Services])

 

 

 

I was assuming Opportunity Services is a measure.

 

If you need any help please let me know.
If I answered your question I would be happy if you could give it a thumbs up 👍!

Best regards
Denis

Hi @selimovd 

 

Thank you so much for your solution it really helps. However, I did run into other issues and I should have been more clear in the beginning. So the goal of the filtered table was so that I could use this formula:

 

if ('Opportunity'[Commit_Upside__c] = "Booked", 'Opportunity'[ToUSD-Positive_Services_Amount] * sum('2021-Assumptions'[Booked%]),
if ('Opportunity'[Commit_Upside__c] = "Commit", 'Opportunity'[ToUSD-Positive_Services_Amount] * sum('2021-Assumptions'[Commit%]),
if ('Opportunity'[Commit_Upside__c] = "Upside", 'Opportunity'[ToUSD-Positive_Services_Amount] * sum('2021-Assumptions'[Upside%]),
if ('Opportunity'[Commit_Upside__c] = "Potential", 'Opportunity'[ToUSD-Positive_Services_Amount] * sum('2021-Assumptions'[Potential%]),
if ('Opportunity'[Commit_Upside__c] = "Pipeline", 'Opportunity'[ToUSD-Positive_Services_Amount] * sum('2021-Assumptions'[Pipeline%]), 0)
))))
 
so if I plug in to your formula it doesn't seem to work because it requires it to be a measure to begin with?

Hey @powerbiwork ,

 

I try to understand where the data is coming from.

What is the table Opportunity and where is the column Commit_Upside__c? Is this another table? Is this in the same table? How would it look if you filter by division?

 

Best regards

Denis

Hi @selimovd 

 

So I have two tables below one from salesforce - opportunity and one from excel 

powerbiwork_4-1614790780618.png

 

powerbiwork_3-1614790756834.png

 

 

I wanted to create a dynamic measure base on a slicer which will be from the excel table and multiply the value to the opportunity table 

powerbiwork_5-1614790812407.png

 

so for example, if the slicer is set to commodities at 2/5/2021 then I want the equation for 2021 assumption to multiply the filtered values :

 

if ('Opportunity'[Commit_Upside__c] = "Booked", 'Opportunity'[ToUSD-Positive-License_Cost__C] * sum('2021-Assumptions'[Booked%]),
if ('Opportunity'[Commit_Upside__c] = "Commit", 'Opportunity'[ToUSD-Positive-License_Cost__C] * sum('2021-Assumptions'[Commit%]),
if ('Opportunity'[Commit_Upside__c] = "Upside", 'Opportunity'[ToUSD-Positive-License_Cost__C] * sum('2021-Assumptions'[Upside%]),
if ('Opportunity'[Commit_Upside__c] = "Potential", 'Opportunity'[ToUSD-Positive-License_Cost__C] * sum('2021-Assumptions'[Potential%]),
if ('Opportunity'[Commit_Upside__c] = "Pipeline", 'Opportunity'[ToUSD-Positive-License_Cost__C] * sum('2021-Assumptions'[Pipeline%]), 0)
))))

 

So I modified your solution to 

Division Factor =
VAR SelectedDivision = SELECTEDVALUE( '2021 Assumptions'[Division] )
VAR SelectedDate = SELECTEDVALUE( '2021 Assumptions'[Date] )
VAR myFilteredTable =
CALCULATETABLE(
'2021 Assumptions',
'2021 Assumptions'[Date] = SelectedDate,
'2021 Assumptions'[Division] = SelectedDivision
)
RETURN
SUMX( myFilteredTable, if (CALCULATETABLE(Opportunity,Opportunity[Commit_Upside__c]) = "Booked"), SUM('Opportunity'[Positive_Services_Amount__c USD]) * sum('2021 Assumptions'[Booked%]),
if (CALCULATETABLE(Opportunity,Opportunity[Commit_Upside__c] = "Commit"), SUM('Opportunity'[Positive_Services_Amount__c USD]) * sum('2021 Assumptions'[Commit%]),
if (CALCULATETABLE(Opportunity,Opportunity[Commit_Upside__c] = "Upside"), SUM('Opportunity'[Positive_Services_Amount__c USD]) * sum('2021 Assumptions'[Upside%]),
if (CALCULATETABLE(Opportunity,Opportunity[Commit_Upside__c] = "Potential"), SUM('Opportunity'[Positive_Services_Amount__c USD]) * sum('2021 Assumptions'[Potential%]),
if (CALCULATETABLE(Opportunity,Opportunity[Commit_Upside__c] = "Pipeline"), SUM('Opportunity'[Positive_Services_Amount__c USD]) * sum('2021 Assumptions'[Pipeline%]), 0)
))))
 
But it doesn't seem like to work

Is it possible?

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.