Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hi, everyone!
I have been struggling for a while to make a measure that would give me a result as shown in the picture below.
Basically, if there is an event then calculate the average for 'selected what-if value' number of days for the event's first date (yellow) and for the next days give the same values (orange). Events should be excluded from average calculation, every Product-Client should be calculated separately (event names may repeat).
The last formula I was at is below. Unfortunately, it gave the wrong average calculation,
Base =
IF (
ISBLANK (
CALCULATE (
FIRSTNONBLANK ( 'Sales'[Event], 'Sales'[Event] ),
FILTER ( ALL ( 'Sales'[Event] ), 'Sales'[Event] <> BLANK () )
)
),
SUMX ( 'Sales', 'Sales'[Volume] ),
SUMX (
'Sales',
CALCULATE (
AVERAGEX ( 'Sales', 'Sales'[Volume] ),
DATESINPERIOD (
'Sales'[Date],
LASTDATE ( 'Sales'[Date].[Date] )-1,
- SELECTEDVALUE ( 'What-if value'[Value], 7 ),
DAY
),
FILTER (
ALLEXCEPT ( 'Sales', 'Sales'[Client], 'Sales'[Product] ),
'Sales'[Event] = BLANK ()
)
)
)
)
Thank you very much for your help!
Solved! Go to Solution.
Hi @JenaT,
You can try to use below measure formula to achieve your requirement:
Dynamic Avg = VAR CurrProduct = FIRSTNONBLANK ( Sales[Product], [Product] ) VAR currClient = FIRSTNONBLANK ( Sales[Client], [Client] ) VAR currEvent = SELECTEDVALUE ( Sales[Event] ) VAR filtered = FILTER ( ALLSELECTED ( Sales ), [Event] = BLANK () && [Product] = CurrProduct && [Client] = currClient && [Date] < MAX ( Sales[Date] ) ) RETURN IF ( currEvent <> BLANK (), AVERAGEX ( FILTER ( ADDCOLUMNS ( filtered, "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] ) ), [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] ) ), [Volume] ) )
Measure used to display correspondent records.
Correspond Items = VAR CurrProduct = FIRSTNONBLANK ( Sales[Product], [Product] ) VAR currClient = FIRSTNONBLANK ( Sales[Client], [Client] ) VAR currEvent = SELECTEDVALUE ( Sales[Event] ) VAR filtered = FILTER ( ALLSELECTED ( Sales ), [Event] = BLANK () && [Product] = CurrProduct && [Client] = currClient && [Date] < MAX ( Sales[Date] ) ) RETURN IF ( currEvent <> BLANK (), CONCATENATEX ( FILTER ( ADDCOLUMNS ( filtered, "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] ) ), [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] ) ), [Volume], "," ) )
Regards,
Xiaoxin Sheng
Hi @JenaT,
You can try to use below measure formula to achieve your requirement:
Dynamic Avg = VAR CurrProduct = FIRSTNONBLANK ( Sales[Product], [Product] ) VAR currClient = FIRSTNONBLANK ( Sales[Client], [Client] ) VAR currEvent = SELECTEDVALUE ( Sales[Event] ) VAR filtered = FILTER ( ALLSELECTED ( Sales ), [Event] = BLANK () && [Product] = CurrProduct && [Client] = currClient && [Date] < MAX ( Sales[Date] ) ) RETURN IF ( currEvent <> BLANK (), AVERAGEX ( FILTER ( ADDCOLUMNS ( filtered, "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] ) ), [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] ) ), [Volume] ) )
Measure used to display correspondent records.
Correspond Items = VAR CurrProduct = FIRSTNONBLANK ( Sales[Product], [Product] ) VAR currClient = FIRSTNONBLANK ( Sales[Client], [Client] ) VAR currEvent = SELECTEDVALUE ( Sales[Event] ) VAR filtered = FILTER ( ALLSELECTED ( Sales ), [Event] = BLANK () && [Product] = CurrProduct && [Client] = currClient && [Date] < MAX ( Sales[Date] ) ) RETURN IF ( currEvent <> BLANK (), CONCATENATEX ( FILTER ( ADDCOLUMNS ( filtered, "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] ) ), [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] ) ), [Volume], "," ) )
Regards,
Xiaoxin Sheng
Thanks!
The Dynamic Avg works well as long as Client and Product are both listed in the table. However, if I remove Product column and the Product data is aggregated (e.g. there are several products with Promo1 in the same period), then the averages are not aggregated and the value for Product1 is again shown. Is there a workaround for this?
Hi @JenaT,
You can try to remove currProduct condition from measure:
Dynamic Avg = VAR currClient = FIRSTNONBLANK ( Sales[Client], [Client] ) VAR currEvent = SELECTEDVALUE ( Sales[Event] ) VAR filtered = FILTER ( ALLSELECTED ( Sales ), [Event] = BLANK () && [Client] = currClient && [Date] < MAX ( Sales[Date] ) ) RETURN IF ( currEvent <> BLANK (), AVERAGEX ( FILTER ( ADDCOLUMNS ( filtered, "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] ) ), [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] ) ), [Volume] ) )
Regards,
Xiaoxin Sheng
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
144 | |
85 | |
65 | |
51 | |
45 |
User | Count |
---|---|
217 | |
88 | |
81 | |
65 | |
56 |