How to get sales value for the previous 12 months from the latest available date in Power BI.

How to get sales value for the previous 12 months from the latest available date in Power BI.

In this post, we are going to find out how to,

  • Getting previous 12 months' sales from today.

  • Getting previous 12 months' sales from the latest available date.

Getting the previous 12 months (or any number of months) is a pretty common requirement in Power BI dashboards. A simple measure would do that.

But what if the dataset is missing data from this month or a few months from the current month? Is there a way to get data for the last 12 months from the previous non-blank month?

Let's find out.

Data Set

we have a set of month names up to March 2023 and sales amounts for each month. And we have a calendar table with dates up to the end of 2023. This can be any date after the last date of sale.

Here is how it looks on a chart.

Last 12 months' sales from today

Let's write a measure to get only the last 12 months' data from today (July 2023).

The latest data available is from March 2023. So ideally we should be able to see data from August 2022 to March 2023, 8 months of data.

Create a new measure and add this.

Previous 12 Months Sales =
CALCULATE (
    SUM ( Sales[Amount] ),
    DATESINPERIOD ( 'Date'[Date].[Date], TODAY (), -12, MONTH )
)

The idea here is to calculate the sales amount within the given date range (12 Months back from today) by the DATESINPERIOD function.

The time intelligence function used here is DATESINPERIOD.

DATESINPERIOD function (DAX) - DAX | Microsoft Learn

Here's the syntax.

DATESINPERIOD(dates column, start date, number of intervals, interval )
TermWhat's used
dates columnDates column from the Calendar table
start dateTODAY ( )
number of intervals-12
intervalMonths (choice)

Add the column to a table or a chart. We get data from the last 12 months. This includes the last 4 months in which sales data is not available.

Getting the previous 12 months' sales from the latest available date.

Okay, let's move on to a little bit advanced case.

In the last measure, even though we specified 12 as the expected number of months, we got only 8 months' worth of results. There is nothing wrong with the measure we created. The problem is that the Sales data table has values only up to March 2023.

But what if we need sales amounts for the previous 12 months starting from last month with data available....?

Let's take a look at the previous measure.

the problem with this formula is that in the place of "from" date we use TODAY(). If we can replace it with "last non-blank sales date" we can easily get the desired results.

Let's write a formula to get the "last non-blank sales date".

Last non blank Date =
CALCULATE ( LASTDATE ( Sales[Date] ), ALL ( Sales ) )

LASTDATE function (DAX) - DAX | Microsoft Learn

ALL function (DAX) - DAX | Microsoft Learn

This formula takes the sales table, removes all external filters, and gets the last date of the dates column. Here's the result.

Let's add that as a variable to the previous measure.

Previous non blank 12 Months Sales = 

VAR Last_non_blank_Date =
    CALCULATE ( LASTDATE ( Sales[Date] ), ALL ( Sales ) )

RETURN
    CALCULATE (
        SUM ( Sales[Amount] ),
        DATESINPERIOD ( 'Date'[Date].[Date], Last_non_blank_Date, -12, MONTH )
    )

Here's the result.

This measure can be used in a chart visual and the last nonblank 12 months can be viewed.

Variable month number

The number of Months filtered is determined by the 3rd argument of the DATESINPERIOD( ) function. You can change this number and/or the direction to get different time ranges.

Conclusion

CALCULATE and DATESINPERIOD functions can be used to get historic data from a table and it can be customized to change the time range.