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

Average for populated columns

Hi,

 

I have 2 tables: factPosition and dimDate. What I'm trying to do is calculate the Average for the closing price, for the last 5 days for each symbol:

 

TestSymbolAverage5Day:=
AVERAGEX (
SUMMARIZE (
DatesInPeriod( V_dimDate[DateValue],LastDate(V_dimDate[DateValue]),-5,DAY),
V_dimDate[DateValue]
),
CALCULATE ( [Sum of ClosePosition] )
)

 

The above works when I have 5 consecutive days however the weekend dates are not populated so the average is incorrect:

Capture.PNG

 

 

How do I change my formular so it only works on the days where I have a "SUM of ClosePrice" populated?

 

Thanks 

Bob

1 ACCEPTED SOLUTION

Make these two changes to your code:

 

TestAverage5days :=
AVERAGEX (
    TOPN (
        5,
        CALCULATETABLE (
            SUMMARIZE ( factEODPosition, dimDate[DateValue] ),
            DATESBETWEEN ( dimDate[DateValue], BLANK (), MAX ( dimDate[DateValue] ) )
        ),
        dimDate[DateValue]
    ),
    CALCULATE ( SUM ( [ClosePosition] ) )
)
  • BLANK() is used so that DATESBETWEEN has now lower bound, and that the top 5 dates are taken from all dates so far.
  • CALCULATE is needed in the 2nd argument of AVERAGEX so that context transition occurs, converting the date row context into filter context (in my example I used a measure which is automatically wrapped in CALCULATE).
  • Not sure why dimDate[DateValue] was highlighted red - just confirming it's definitely a column of type Date?

Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

3 REPLIES 3
OwenAuger
Super User
Super User

Hi @BeginnerBob

 

I am assuming that factPosition only contains rows with populated ClosePosition values, so that the dates existing in factPosition are populated dates. 

 

If so, then try a measure like this:

 

Average Sum of ClosePosition for last 5 populated dates = 
AVERAGEX (
    TOPN (
        5,
        CALCULATETABLE (
            SUMMARIZE ( factPosition, dimDate[Date] ),
            DATESBETWEEN ( dimDate[Date], BLANK (), MAX ( dimDate[Date] ) )
        ),
        dimDate[Date]
    ),
    [Sum of ClosePosition]
)

The code in green returns a table of dates which exist in factPosition up to the max date in the filter context. Then TOPN grabs the top (i.e. latest) 5 of these.

 

In order to suppress this measure when you have gone past the last date in factPosition, you could add a check to the measure:

 

Average Sum of ClosePosition for last 5 populated dates =
IF (
    MIN ( dimDate[Date] )
        <= CALCULATE ( MAX ( factPosition[Date] ), ALL ( factPosition ) ),
    AVERAGEX (
        TOPN (
            5,
            CALCULATETABLE (
                SUMMARIZE ( factPosition, dimDate[Date] ),
                DATESBETWEEN ( dimDate[Date], BLANK (), MAX ( dimDate[Date] ) )
            ),
            dimDate[Date]
        ),
        [Sum of ClosePosition]
    )
)

Regards,

Owen 🙂


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

HI,

 

Thanks for you response. This doesn't seem to work the values which are returned are the close position:

 

TestAverage5days:=AVERAGEX (
TOPN (
5,
CALCULATETABLE (
SUMMARIZE ( factEODPosition, dimDate[DateValue]),
DATESBETWEEN ( dimDate[DateValue], MIN ( dimDate[DateValue]) , MAX (dimDate[DateValue]) )
),
dimDate[DateValue]
),
SUM( [ClosePosition])
)

My dimDate[DateValue] is highlighted red, which is a little strange. My code compliles but an average isn't returned, just the SUM[ClosePosition].

 

Any ideas?

 

Thanks

 

Make these two changes to your code:

 

TestAverage5days :=
AVERAGEX (
    TOPN (
        5,
        CALCULATETABLE (
            SUMMARIZE ( factEODPosition, dimDate[DateValue] ),
            DATESBETWEEN ( dimDate[DateValue], BLANK (), MAX ( dimDate[DateValue] ) )
        ),
        dimDate[DateValue]
    ),
    CALCULATE ( SUM ( [ClosePosition] ) )
)
  • BLANK() is used so that DATESBETWEEN has now lower bound, and that the top 5 dates are taken from all dates so far.
  • CALCULATE is needed in the 2nd argument of AVERAGEX so that context transition occurs, converting the date row context into filter context (in my example I used a measure which is automatically wrapped in CALCULATE).
  • Not sure why dimDate[DateValue] was highlighted red - just confirming it's definitely a column of type Date?

Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

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.