Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
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:
How do I change my formular so it only works on the days where I have a "SUM of ClosePrice" populated?
Thanks
Bob
Solved! Go to 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] ) )
)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 🙂
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] ) )
)Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
| User | Count |
|---|---|
| 92 | |
| 69 | |
| 50 | |
| 40 | |
| 38 |