cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
J-Saw
Frequent Visitor

Need Help: Persistent Moving/Rolling Average

Is there a DAX formula to persist, or hold, the lastest value of the rolling/moving average whenever data points are over and to extend it thru time? 

1 ACCEPTED SOLUTION

Accepted Solutions
Anonymous
Not applicable

Re: Need Help: Persistent Moving/Rolling Average

@J-Saw I'm sorry for that.
I'll try and see if I can get LastNonBlank to work. I propose an alternative solution. 
Get the lastdate where price/box is not blank. Look up the price/box for that date.
=
VAR lastPriceDate =
    CALCULATE (
        MAX ( Table1[Date] );
        ALLEXCEPT ( Table1; Table1[Product] );
        NOT ( ISBLANK ( Table1[Price/Box] ) )
    )
VAR LastPrice =
    CALCULATE (
        MAX ( Table1[Price/Box] );
        ALL ( Table1 );
        VALUES ( Table1[Product] );
        Table1[Date] = lastPriceDate
    )
RETURN
    IF ( ISBLANK ( Table1[Price/Box] ); LastPrice; Table1[Price/Box] )


oops.JPG
Cheers,
Pedro








View solution in original post

5 REPLIES 5
Community Support
Community Support

Re: Need Help: Persistent Moving/Rolling Average

Hi J-Saw,

 

Maybe something like LASTDATE() or LASTNONBLAMK(), if can't meet your requirement, please share some sample data and clarify more details about your requirement or logic.

 

Regards,

Jimmy Tao

Highlighted
J-Saw
Frequent Visitor

Re: Need Help: Persistent Moving/Rolling Average

@v-yuta-msft

Date                    Product   Boxes       Prices      Price/Box

2018-01-011710$1.43
2018-01-012512$2.40
2018-02-011910$1.11
2018-02-012612$2.00
2018-03-011   
2018-03-012   

 

So basically would be having the Price/Box for 2018-03-01 using the most recent Price/Box for product 1 and 2.

Anonymous
Not applicable

Re: Need Help: Persistent Moving/Rolling Average

If what you're looking for is a calculated column, you can do the following:

=
IF (
    ISBLANK ( Table1[Price/Box] );
    CALCULATE (
        LASTNONBLANK ( Table1[Price/Box]; 1 );
        ALLEXCEPT ( Table1; Table1[Product] )
    );
    Table1[Price/Box]
)

calColumn.JPGLast Price

 

To make the "Last Price" clear I chose to put in datetime information.

 

J-Saw
Frequent Visitor

Re: Need Help: Persistent Moving/Rolling Average

@Anonymous

Thanks. This is very helpful. However is not showing the most recent(February) Price/Box.

Anonymous
Not applicable

Re: Need Help: Persistent Moving/Rolling Average

@J-Saw I'm sorry for that.
I'll try and see if I can get LastNonBlank to work. I propose an alternative solution. 
Get the lastdate where price/box is not blank. Look up the price/box for that date.
=
VAR lastPriceDate =
    CALCULATE (
        MAX ( Table1[Date] );
        ALLEXCEPT ( Table1; Table1[Product] );
        NOT ( ISBLANK ( Table1[Price/Box] ) )
    )
VAR LastPrice =
    CALCULATE (
        MAX ( Table1[Price/Box] );
        ALL ( Table1 );
        VALUES ( Table1[Product] );
        Table1[Date] = lastPriceDate
    )
RETURN
    IF ( ISBLANK ( Table1[Price/Box] ); LastPrice; Table1[Price/Box] )


oops.JPG
Cheers,
Pedro








View solution in original post

Helpful resources

Announcements
‘Better Together’ T-Shirt Contest – Winner Announced!

‘Better Together’ T-Shirt Contest – Winner Announced!

And the winner is...

Announcing the New Spanish Forum

Announcing the New Spanish Forum

Do you need help in Spanish? Check out our new Spanish community section.

April 2020 Community Highlights

April 2020 Community Highlights

Info on our Super Users, MBAS content and badges, and updates to our support articles. - Read the full Community Highlights.

MBAS Gallery 2020

MBAS Gallery 2020

Watch Microsoft Business Applications Summit sessions on-demand.

Top Solution Authors
Top Kudoed Authors