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

YTD and Monthly sales in the same table. Also how do I make it interactive with a filter?

I want to create a table with this information:

Monthy Sales 2019 --  Monthly Sales 2020 -- % Difference -- YTD Sales 2019 --- YTD Sales 2020 -- % Difference

I want to have a filter were I select "October" for example, and it gives me montly sales for October  and the YTD from Jan to Oct.

I don´t know if I explained myself. Thank you very much!

1 ACCEPTED SOLUTION
v-jayw-msft
Community Support
Community Support

Hi @Anonymous ,

 

Here's my sample data and I create some calculated columns.

year = YEAR('Table'[date])

month = FORMAT('Table'[date],"MMMM")

monthnum = MONTH('Table'[date])

6.PNG

And here's my measures.

monthly_2019 = CALCULATE(SUM('Table'[value]),FILTER(ALLEXCEPT('Table','Table'[month]),'Table'[year]=2019))

monthly_2020 = CALCULATE(SUM('Table'[value]),FILTER(ALLEXCEPT('Table','Table'[month]),'Table'[year]=2020))

%diff = ([monthly_2020]-[monthly_2019])/[monthly_2019]

ytd2019 = CALCULATE(SUM('Table'[value]),FILTER(ALLSELECTED('Table'),'Table'[monthnum]<MAX('Table'[monthnum])+1&&'Table'[year]=2019))

ytd2020 = CALCULATE(SUM('Table'[value]),FILTER(ALLSELECTED('Table'),'Table'[monthnum]<MAX('Table'[monthnum])+1&&'Table'[year]=2020))

ytd%diff = ([ytd2020]-[ytd2019])/[ytd2019]

And the result would be shown as below.

7.PNG

8.PNG

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

2 REPLIES 2
v-jayw-msft
Community Support
Community Support

Hi @Anonymous ,

 

Here's my sample data and I create some calculated columns.

year = YEAR('Table'[date])

month = FORMAT('Table'[date],"MMMM")

monthnum = MONTH('Table'[date])

6.PNG

And here's my measures.

monthly_2019 = CALCULATE(SUM('Table'[value]),FILTER(ALLEXCEPT('Table','Table'[month]),'Table'[year]=2019))

monthly_2020 = CALCULATE(SUM('Table'[value]),FILTER(ALLEXCEPT('Table','Table'[month]),'Table'[year]=2020))

%diff = ([monthly_2020]-[monthly_2019])/[monthly_2019]

ytd2019 = CALCULATE(SUM('Table'[value]),FILTER(ALLSELECTED('Table'),'Table'[monthnum]<MAX('Table'[monthnum])+1&&'Table'[year]=2019))

ytd2020 = CALCULATE(SUM('Table'[value]),FILTER(ALLSELECTED('Table'),'Table'[monthnum]<MAX('Table'[monthnum])+1&&'Table'[year]=2020))

ytd%diff = ([ytd2020]-[ytd2019])/[ytd2019]

And the result would be shown as below.

7.PNG

8.PNG

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.
amitchandak
Super User
Super User

@Anonymous , Try with Time Intelligence with Date table

 

example

MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD('Date'[Date]))
last year MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(dateadd('Date'[Date],-12,MONTH)))
last year MTD (complete) Sales =  CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(ENDOFMONTH(dateadd('Date'[Date],-12,MONTH))))

diff = [MTD Sales]-[last year MTD Sales]
diff % = divide([MTD Sales]-[last year MTD Sales],[last year MTD Sales])

 

YTD

YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD('Date'[Date],"12/31"))
Last YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(dateadd('Date'[Date],-1,Year),"12/31"))
This year Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(ENDOFYEAR('Date'[Date]),"12/31"))
Last year Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(ENDOFYEAR(dateadd('Date'[Date],-1,Year)),"12/31"))
Last to last YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(dateadd('Date'[Date],-2,Year),"12/31"))
Year behind Sales = CALCULATE(SUM(Sales[Sales Amount]),dateadd('Date'[Date],-1,Year))

 

 

Power BI — Year on Year with or Without Time Intelligence
https://medium.com/@amitchandak.1978/power-bi-ytd-questions-time-intelligence-1-5-e3174b39f38a
Power BI — Qtr on Qtr with or Without Time Intelligence
https://medium.com/@amitchandak.1978/power-bi-qtd-questions-time-intelligence-2-5-d842063da839
Power BI — Month on Month with or Without Time Intelligence
https://medium.com/@amitchandak.1978/power-bi-mtd-questions-time-intelligence-3-5-64b0b4a4090e

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :radacad sqlbi My Video Series Appreciate your Kudos.

 

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.