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
Anonymous
Not applicable

Best 12 month period within last 5 years

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

2 ACCEPTED SOLUTIONS
DataInsights
Super User
Super User

@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):

 

DataInsights_0-1652372714777.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

Anonymous
Not applicable

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! 🙂

View solution in original post

2 REPLIES 2
DataInsights
Super User
Super User

@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):

 

DataInsights_0-1652372714777.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Anonymous
Not applicable

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! 🙂

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.