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 Peeps,
I have a dataset which includes a table with the following columns; Cust ID, Invoiced Revenue, Invoiced Date.
I need to be able to query this data to confirm the total revenue for the best 12 month period throughout the last 5 years, and am really struggling. 😞
The 12 months need to be consecutive, but do not need to align to calendar years. The 5 year range is relative to today's date.
I'm concerned this would require calculating the Invoiced Revenue for each of the individual 12 month ranges within the 60 months timeframe, and then returning the maximum value, and this might come with a heavy processing overhead - especially as I have ~64k Customers!!
Anyone got any bright ideas how to go about this in a performant manner?
Thanks
Chris
Solved! Go to Solution.
@Anonymous,
Try this solution. The concept is to calculate a rolling 12 month total in a calculated column, and then use a measure to get the highest amount in the calculated column. Shifting the rolling 12 month calculation to a calculated column pre-calculates the amounts (occurs in the dataset refresh), which should perform better than doing all the calculations in a measure.
Calculated column:
Rolling 12 Month Revenue =
VAR vInvoicedDate = Invoices[Invoiced Date]
VAR vResult =
CALCULATE (
SUM ( Invoices[Invoiced Revenue] ),
ALLEXCEPT (
Invoices,
Invoices[Cust ID]
),
Invoices[Invoiced Date] > vInvoicedDate - 365,
Invoices[Invoiced Date] <= vInvoicedDate
)
RETURN
vResult
Measure:
Best 12 Month Revenue = MAX ( Invoices[Rolling 12 Month Revenue] )
You can control the date range with a date slicer (Relative Date):
Proud to be a Super User!
Thanks @DataInsights . I think this works conceptually, yes, although the business requirement is now in question and I may not need to build this into a live report for the time being! 🙂
@Anonymous,
Try this solution. The concept is to calculate a rolling 12 month total in a calculated column, and then use a measure to get the highest amount in the calculated column. Shifting the rolling 12 month calculation to a calculated column pre-calculates the amounts (occurs in the dataset refresh), which should perform better than doing all the calculations in a measure.
Calculated column:
Rolling 12 Month Revenue =
VAR vInvoicedDate = Invoices[Invoiced Date]
VAR vResult =
CALCULATE (
SUM ( Invoices[Invoiced Revenue] ),
ALLEXCEPT (
Invoices,
Invoices[Cust ID]
),
Invoices[Invoiced Date] > vInvoicedDate - 365,
Invoices[Invoiced Date] <= vInvoicedDate
)
RETURN
vResult
Measure:
Best 12 Month Revenue = MAX ( Invoices[Rolling 12 Month Revenue] )
You can control the date range with a date slicer (Relative Date):
Proud to be a Super User!
Thanks @DataInsights . I think this works conceptually, yes, although the business requirement is now in question and I may not need to build this into a live report for the time being! 🙂
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 |
---|---|
145 | |
85 | |
66 | |
52 | |
48 |
User | Count |
---|---|
215 | |
90 | |
83 | |
67 | |
59 |