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
kt_powerbiuser
Frequent Visitor

Rolling total of calculated measure

Hello,

I am trying to calculate measure Rolling Total like on screenshot below. Measures Sent and Returns are coming from one table, and the Delivery number is an attribute from related table which is connected by relationship.

4.PNG 

 

Cancellation is calculated measure and we are using formulas like below:

Cancellations :=

VAR NextPack =

    MAX ( 'Order'[DeliveryNumber] ) + 1

 

VAR NextOrders =

    CALCULATE (

        SUM ( 'Fact Rolling'[Sent] ) - SUM ( 'Fact Rolling'[Returned] ),

        'Order'[DeliveryNumber] = NextPack

    )

 

VAR CurrentOrders =

    IF (

        NextPack = 1,

        CALCULATE (

            SUM ( 'Fact Subscriptions'[NewSubscriptions] ),

            'Order'[DeliveryNumber] = 0

        ),

        SUM ( 'Fact Rolling'[Sent] ) - SUM ( 'Fact Rolling'[Returned] )

            - SUM ( 'Fact Rolling'[ActiveSubscriptions] )

    )

 

RETURN

    IF (

        ISBLANK ( MAX ( 'Order'[DeliveryNumber] ) ),

        BLANK (),

        CurrentOrders - NextOrders

    )

----------

Cancellation % (DropOff):=

VAR Netto =

    IF (

        MAX ( 'Order'[DeliveryNumber] ) = 0,

        CALCULATE (

            SUM ( 'Fact Subscriptions'[NewSubscriptions] ),

            'Order'[DeliveryNumber] = 0

        ),

        [Netto]

    )

RETURN

    DIVIDE ( [Cancellations (Rolling Total)], Netto )

As it should be calculated dynamically we are trying calculate Rolling Total like below

DropOff (DropOff):=

 CALCULATE(

 IF (

        ISBLANK ( MAX ( 'Order'[DeliveryNumber] ) ),

        BLANK (),

        [Cancellation % (Rolling Total)]

    ), FILTER(ALL('Order'[DeliveryNumber]), 'Order'[DeliveryNumber] <= MAX('Order'[DeliveryNumber])))

But calculation still not returns data like in presented table. We are receiving data like below2.PNG

We assuming we have problem with below part, but have no idea how to calculate it in other way.

VAR NextPack =

    MAX ( 'Order'[DeliveryNumber] ) + 1

 

Calculation for cancellation base on below formula:

5.png

 

1 ACCEPTED SOLUTION

Hi @kt_powerbiuser,

 

From your measures, I found that we cannot calculate the Rolling total before should be caused by the context. 

 

You could modify your formula refer to the measure below.

 

Rolling Total =
CALCULATE (
    SUMX (
        ADDCOLUMNS (
            SUMMARIZE ( 'Fact DropOff', 'Order'[PactDelivered] ),
            "Value", [Cancellation % (DropOff)]
        ),
        [Value]
    ),
    FILTER (
        ALL ( 'Order'[PactDelivered] ),
        'Order'[PactDelivered] <= MAX ( 'Order'[PactDelivered] )
    )
)

Then you should get the right Roliing total.

 

Untitled.png

 

Hope this can help you!

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
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-piga-msft
Resident Rockstar
Resident Rockstar

Hi @kt_powerbiuser,

 

Although you have posted the details information, I still need more details such as your another table Fact Subscriptions.

 

If it is conventient, could you share a dummy pbix file which can reproduce the scenario, so that we can help further investigate on it? You can upload it to OneDrive or Dropbox and post the link here. Do mask sensitive data before uploading.)

 

Best Regards,

Cherry

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

Hello @v-piga-msft,

 

Thank you for your reply. I put here crucial part of my model https://drive.google.com/open?id=1achCPQpKEv1w5iXnJiaMLAIKD92k8f60.

I will be very gratefull for some tips.

 

Regards,

kt

Hi @kt_powerbiuser,

 

From your measures, I found that we cannot calculate the Rolling total before should be caused by the context. 

 

You could modify your formula refer to the measure below.

 

Rolling Total =
CALCULATE (
    SUMX (
        ADDCOLUMNS (
            SUMMARIZE ( 'Fact DropOff', 'Order'[PactDelivered] ),
            "Value", [Cancellation % (DropOff)]
        ),
        [Value]
    ),
    FILTER (
        ALL ( 'Order'[PactDelivered] ),
        'Order'[PactDelivered] <= MAX ( 'Order'[PactDelivered] )
    )
)

Then you should get the right Roliing total.

 

Untitled.png

 

Hope this can help you!

 

Best Regards,

Cherry

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

Thank You @v-piga-msft !

It works 🙂

Best Regards,

Kate

kt_powerbiuser
Frequent Visitor

Hello,

I am trying to calculate measure DroppOff like on screenshot below. Measures Orders sent ot and Returns are coming from one table, and the PactDelivered is an attribute from related table which is connected by relationship.

 

 1.PNG

Cancellation is calculated measure and we are using formulas like below:

Cancellations (DropOff):=

VAR NextPack =

    MAX ( 'Order'[PactDelivered] ) + 1

 

VAR NextOrders =

    CALCULATE (

        SUM ( 'Fact DropOff'[OrdersSentOut] ) - SUM ( 'Fact DropOff'[OrdersReturned] ),

        'Order'[PactDelivered] = NextPack

    )

 

VAR CurrentOrders =

    IF (

        NextPack = 1,

        CALCULATE (

            SUM ( 'Fact Subscriptions'[NewSubscriptions] ),

            'Order'[PactDelivered] = 0

        ),

        SUM ( 'Fact DropOff'[OrdersSentOut] ) - SUM ( 'Fact DropOff'[OrdersReturned] )

            - SUM ( 'Fact DropOff'[ActiveSubscriptions] )

    )

 

RETURN

    IF (

        ISBLANK ( MAX ( 'Order'[PactDelivered] ) ),

        BLANK (),

        CurrentOrders - NextOrders

    )

----------

Cancellation % (DropOff):=

VAR Netto =

    IF (

        MAX ( 'Order'[PactDelivered] ) = 0,

        CALCULATE (

            SUM ( 'Fact Subscriptions'[NewSubscriptions] ),

            'Order'[PactDelivered] = 0

        ),

        [Netto]

    )

RETURN

    DIVIDE ( [Cancellations (DropOff)], Netto )

As it should be calculated dynamically we are trying calculate DropOff like below

DropOff (DropOff):=

 CALCULATE(

 IF (

        ISBLANK ( MAX ( 'Order'[PactDelivered] ) ),

        BLANK (),

        [Cancellation % (DropOff)]

    ), FILTER(ALL('Order'[PactDelivered]), 'Order'[PactDelivered] <= max('Order'[PactDelivered])))

But calculation still not returns data like in presented table. We are receiving data like below2.PNG

We assuming we have problem with part

VAR NextPack =

    MAX ( 'Order'[PactDelivered] ) + 1

But have no idea how to calculate it in other way.

 

EDIT:

Calculation for cancellation base on below formula:

3.png

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.