cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Landcrab Frequent Visitor
Frequent Visitor

Cumulative total for WHATIF parameters

Hi there,

Is it possible to calculate the cumulative amount for two WHATIF parameters?

 

I have a date table and I am able to calculate cumulative total for all my other amounts that have a date by which I can associate the table that contains the amount with my date table.

 

This measure works for tables associated with date table:

 

Cumulative Amount =
       CALCULATE (

            SUM ( Amount ),

                FILTER( ALL( Dates[Date] ),

                     Dates[Date] <= MAX( Dates[Date )

                )

        )

 

But since WHATIF parameters have no date associated with them, I cannot figure out how to do cumulative total?? 😞

 

WHATIF parameter 1

NoOfDocuments = GENERATESERIES(100, 15000, 100)
 
WHATIF parameter 2
AmountPerDocument = GENERATESERIES(10, 15.5, 0.25)
 
CostOfDocuments = SELECTEDVALUE( NoOfDocuments ) * SELECTEDVALUE( AmountPerDocument )
 
Below measure will not work for parameters..
 
CostOfDocsCumulative =

CALCULATE (

    [CostOfDocuments] ,

          FILTER( ALL( Dates[Date] ),

               Dates[Date] <= MAX( Dates[Date )

           )

)

 

Any help is much appreciated.

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Landcrab Frequent Visitor
Frequent Visitor

Re: Cumulative total for WHATIF parameters

Hi Jay,

 

Yes that's my conclusion as well, it cannot be done using just WHATIF parameters alone.

 

My workaround has been to create a new table containing the MIN value for the two variables and a date column allowing it to be linked to date table.

 

Then create two WHATIF paramters for the same variables with the desired range starting at the same MIN value from the column.

Then created two new measures that link the column with the WHATIF parameters to increase the 'No of Docs' and/ or 'Amount' as per user input. This then enables me to create cumulative figure for them because they are now linked to the date table.


New table 'Current Cost'

Month Number NoOfDocs Amount
1 100 10
2 100 10
3 100 10...etc

 

WHATIF parameter 1
NoOfDocs = GENERATESERIES(100, 5000, 100)

WHATIF parameter 2
Amount = GENERATESERIES(10, 15.5, 0.25)


Work out the amount:

Current Cost Total =

VAR NumOfDocsToBeAdded =
IF( [NoOfDocs] = 100, 0, [NumberOfDocumentsMetric Value] - 100 )

// 'NumOfDocsToBeAdded' variable used to work out if WHATIF value has increased and if so work out by how much compared to MIN (100)


VAR CurrentCostPerDocToBeAdded =
IF( [Amount] = 10, 0, [CurrentCostMetric Value] - 10 )

// 'CurrentCostPerDocToBeAdded' variable used to work out if WHATIF value has increased and if so work out by how much compared to MIN (10)


RETURN
CALCULATE(
SUMX( 'Current Cost', ( 'Current Cost'[Amount] + CurrentCostPerDocToBeAdded ) * ( 'Current Cost'[NoOfDocs] + NumOfDocsToBeAdded ) ),
CROSSFILTER( 'Current Cost'[Month Number], 'Calendar'[Begining Start Month Number], Both )
)

 


Cumulative Total:


Cumulative Current Cost =
CALCULATE(
[Current Cost Total],
FILTER( ALL( 'Calander' ),
'Calendar'[Date] <= MAX( 'Calendar'[Date] ) )


That worked for me.

 

 

View solution in original post

2 REPLIES 2
v-jayw-msft Senior Member
Senior Member

Re: Cumulative total for WHATIF parameters

Hi @Landcrab ,

 

As far as I know, if you want to calculate the cumulative amount with Dates table there should be a relationship between them.

For example:

Amount table:

5.PNG

Dates table:

6.PNG

Cumulative Amount =

CALCULATE (

    SUM ( amount[amount] ),

    FILTER ( ALL ( Dates[Date] ), Dates[Date] <= MAX ( dates[date] ) )

)

Relationship inactive:

2.PNG3.PNG

Relationship active:

1.PNG4.PNG

As we know there is no relationship between Dates table and either NoOfDocuments nor AmountPerDocument so the measure will not work for them.

 

Best Regards,

Jay

 

Community Support Team _ Jay Wang

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

Highlighted
Landcrab Frequent Visitor
Frequent Visitor

Re: Cumulative total for WHATIF parameters

Hi Jay,

 

Yes that's my conclusion as well, it cannot be done using just WHATIF parameters alone.

 

My workaround has been to create a new table containing the MIN value for the two variables and a date column allowing it to be linked to date table.

 

Then create two WHATIF paramters for the same variables with the desired range starting at the same MIN value from the column.

Then created two new measures that link the column with the WHATIF parameters to increase the 'No of Docs' and/ or 'Amount' as per user input. This then enables me to create cumulative figure for them because they are now linked to the date table.


New table 'Current Cost'

Month Number NoOfDocs Amount
1 100 10
2 100 10
3 100 10...etc

 

WHATIF parameter 1
NoOfDocs = GENERATESERIES(100, 5000, 100)

WHATIF parameter 2
Amount = GENERATESERIES(10, 15.5, 0.25)


Work out the amount:

Current Cost Total =

VAR NumOfDocsToBeAdded =
IF( [NoOfDocs] = 100, 0, [NumberOfDocumentsMetric Value] - 100 )

// 'NumOfDocsToBeAdded' variable used to work out if WHATIF value has increased and if so work out by how much compared to MIN (100)


VAR CurrentCostPerDocToBeAdded =
IF( [Amount] = 10, 0, [CurrentCostMetric Value] - 10 )

// 'CurrentCostPerDocToBeAdded' variable used to work out if WHATIF value has increased and if so work out by how much compared to MIN (10)


RETURN
CALCULATE(
SUMX( 'Current Cost', ( 'Current Cost'[Amount] + CurrentCostPerDocToBeAdded ) * ( 'Current Cost'[NoOfDocs] + NumOfDocsToBeAdded ) ),
CROSSFILTER( 'Current Cost'[Month Number], 'Calendar'[Begining Start Month Number], Both )
)

 


Cumulative Total:


Cumulative Current Cost =
CALCULATE(
[Current Cost Total],
FILTER( ALL( 'Calander' ),
'Calendar'[Date] <= MAX( 'Calendar'[Date] ) )


That worked for me.

 

 

View solution in original post

Helpful resources

Announcements
New Topics Started Badges Coming

New Topics Started Badges Coming

We're releasing new versions of the badge that everyone's talking about. ;) Check your inbox for notifications.

MBAS 2020

Save the new date (and location)!

Our business applications community is growing—so we needed a different venue, resulting in a new date and location. See you there!

Difinity Conference

Difinity Conference

The largest Power BI, Power Platform, and Data conference in New Zealand

Power Platform 2019 release wave 2 plan

Power Platform 2019 release wave 2 plan

Features releasing from October 2019 through March 2020

Top Solution Authors
Top Kudoed Authors (Last 30 Days)