Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
trptl
Frequent Visitor

Average of last N values skipping blank values

Hello,

 

I need help on this. I am trying to develope a mesure to caclulate an average of last N entries (in this case 3 "working" days) of sales, when the table contains blank values for certain days (i.e. "non-working" days). The table has other columns with data under "non-working" days. So how can I go about creating a measure for this?

 

A sample data is as follow:

 

DateSalesLast 3 Sales Average
6/1/2020$5,343.00 
6/2/2020$2,345.00 
6/3/2020$7,532.00$5,073.33
6/4/2020  
6/5/2020  
6/6/2020$2,343.00$4,073.33
6/7/2020  
6/8/2020$6,342.00$5,405.67
6/9/2020$2,342.00$3,675.67
6/10/2020$3,523.00$4,069.00
6/11/2020$4,325.00$3,396.67
6/12/2020  
6/13/2020  
6/14/2020  
6/15/2020  
6/16/2020  
6/17/2020$3,234.00$3,694.00
6/18/2020$3,245.00$3,239.50
6/19/2020$1,234.00$2,571.00
6/20/2020$2,345.00$2,274.67

 

For instance, for 6/20, it's AVE[6/20, 6/19, 6/18]; for 6/17, it's AVE[6/17, 6/11, 6/10]; for 6/8, it's AVE[6/8, 6/6, 6/3]; so forth.

 

Thank you.

1 ACCEPTED SOLUTION
mahoneypat
Employee
Employee

Please try this expression that gets your desired results from your sample data.

 

Last 3 WD Sum =
VAR __thisdate =
    MIN ( Sales[Date] )
VAR __top3 =
    TOPN (
        3,
        FILTER ( FILTER ( ALL ( Sales ), Sales[Date] <= __thisdate ), Sales[Sales] > 0 ),
        Sales[Date], DESC
    )
RETURN
    IF (
        OR ( COUNTROWS ( __top3 ) < 3, ISBLANK ( SUM ( Sales[Sales] ) ) ),
        BLANK (),
        CALCULATE ( AVERAGE ( Sales[Sales] ), __top3 )
    )

 

If this works for you, please mark it as the solution.  Kudos are appreciated too.  Please let me know if not.

Regards,

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


View solution in original post

3 REPLIES 3
mahoneypat
Employee
Employee

Please try this expression that gets your desired results from your sample data.

 

Last 3 WD Sum =
VAR __thisdate =
    MIN ( Sales[Date] )
VAR __top3 =
    TOPN (
        3,
        FILTER ( FILTER ( ALL ( Sales ), Sales[Date] <= __thisdate ), Sales[Sales] > 0 ),
        Sales[Date], DESC
    )
RETURN
    IF (
        OR ( COUNTROWS ( __top3 ) < 3, ISBLANK ( SUM ( Sales[Sales] ) ) ),
        BLANK (),
        CALCULATE ( AVERAGE ( Sales[Sales] ), __top3 )
    )

 

If this works for you, please mark it as the solution.  Kudos are appreciated too.  Please let me know if not.

Regards,

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Thanks so much to @mahoneypat , @parry2k  for your elegant soluations.

 

The data set has an additional column with a location. So there are potentially N entries for a given date for N locations. I tried @parry2k's solution, but it didn't work out as expected; however it did for one location data set. For this reason, I ended up using @mahoneypat's solution, and it scales to what I have been looking for. I did though make a minor change:  "FILTER(ALL(Sales)" -> "FILTER(ALLSELECTED(Sales)" to allow filters set for the report.

parry2k
Super User
Super User

@trptl here is something I can think of right now but it can be surely improved but hope it get you started

 

First add a rank column

 

Date Rank = IF ( Data[Sales] <> BLANK(), RANKX ( FILTER( 'Data', Data[Sales] <> BLANK() ) , 'Data'[Date], , ASC ) ) 

 

Now add an average measure

 

Avg Measure = 
VAR __endRank = MAX ( Data[Date Rank] )
VAR __startRank = MAX ( __endRank - 2, 1 )
VAR __avgDenominator = ( __endRank - __startRank ) + 1
RETURN
DIVIDE (
    CALCULATE (
        SUM ( Data[Sales] ),
        ALL ( Data ),    
        Data[Date Rank] >= __startRank,
        Data[Date Rank] <= __endRank
    ), __avgDenominator
)

 

check this out and see if it gets you what you are looking for, here is the output

image.png

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



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.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.