Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Daxmax
Helper I
Helper I

Calculate cumulative sum from beginning of year to filter selection

I have 2 tables

1. Calendar - Contains columns for year, quarter, YearQuarter

 

2. Sales - contains columns for Entity sold, sale price, date of sale, quarter of sale, year of sale.

 

I have a filter in my dashboard for Year and Quarter. I would like to create a measure that calculates the cumulative sum of sales from the beginning of selected year, to the selected quarter.

e.g. if Year = 2020, and Quarter = Q3, the measure should cacluate the sum of sales from beginning of 2020 until the end of Q3 2020.

 

Pictures given below. 

Thanks for your help

 

Data Model.pngData.pngDashboard.png

1 ACCEPTED SOLUTION
v-henryk-mstf
Community Support
Community Support

Hi @Daxmax ,

 

According to your requirements, you need to remove the relationship between the two tables, otherwise the results of the filter will affect the sales table. I did the following test:

M = 
VAR m =
    SELECTEDVALUE ( 'Calendar'[Year] )
VAR n =
    SELECTEDVALUE ( 'Calendar'[YearQuarterNumber] )
VAR a =
    CALCULATE (
        SUM ( Sales[Sales Amount] ),
        FILTER (
            'Sales',
            'Sales'[Year] = m
                && 'Sales'[YearQuarter] <= n
                && 'Sales'[YearQuarter] >= VALUE ( CONCATENATE ( m, "01" ) )
        )
    )
RETURN
    a

v-henryk-mstf_1-1617871178440.png

 

Here is the sample pbix file.


If the problem is still not resolved, please provide detailed error information and let me know immediately. Looking forward to your reply.

Best Regards,
Henry

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

6 REPLIES 6
v-henryk-mstf
Community Support
Community Support

Hi @Daxmax ,

 

According to your requirements, you need to remove the relationship between the two tables, otherwise the results of the filter will affect the sales table. I did the following test:

M = 
VAR m =
    SELECTEDVALUE ( 'Calendar'[Year] )
VAR n =
    SELECTEDVALUE ( 'Calendar'[YearQuarterNumber] )
VAR a =
    CALCULATE (
        SUM ( Sales[Sales Amount] ),
        FILTER (
            'Sales',
            'Sales'[Year] = m
                && 'Sales'[YearQuarter] <= n
                && 'Sales'[YearQuarter] >= VALUE ( CONCATENATE ( m, "01" ) )
        )
    )
RETURN
    a

v-henryk-mstf_1-1617871178440.png

 

Here is the sample pbix file.


If the problem is still not resolved, please provide detailed error information and let me know immediately. Looking forward to your reply.

Best Regards,
Henry

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you. This works!

amitchandak
Super User
Super User

@Daxmax , You have the date, with help from your calendar. You can try measure like

 

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"))

 

or

 

QTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESQTD(('Date'[Date])))
Last QTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESQTD(dateadd('Date'[Date],-1,QUARTER)))

 

 

refer:

Power BI — Year on Year with or Without Time Intelligence
https://medium.com/@amitchandak.1978/power-bi-ytd-questions-time-intelligence-1-5-e3174b39f38a
https://www.youtube.com/watch?v=km41KfM_0uA
Power BI — Qtr on Qtr with or Without Time Intelligence
https://medium.com/@amitchandak.1978/power-bi-qtd-questions-time-intelligence-2-5-d842063da839
https://www.youtube.com/watch?v=8-TlVx7P0A0

Anonymous
Not applicable

@amitchandak , Hi your reply helped me for one of the problem i am trying to solve. But I have bit of twist.  The scenerio I have is for 2021 Fiscal Year starts June 28 and fiscal year < 2021 starts June 30. Can the year end literal be applied based on a condition? I tried both formulas below, but getting DAX error. Any help would be really appreciated.

 

YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD('Date'[Date], IF(YEAR('Date'[Date]) = 2021, "6/27","6/30")))

 

YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD('Date'[Date], (IF(YEAR('Date'[Date]) = 2021, "6/27","6/30"))))

Thanks for your response. My calendar table doesnt have a date field. It only contains Quarter and Year. 

I tried using your formula but it doesn't seem to work.

I've edited my question to include pictures in case that helps.

 

Thanks once agian

@Daxmax , You can check my QTD blog, without Time intelligence, which I share in the last blog.

 

new columns  in a new Year Qtr Table (Say Date) 

Qtr Year = year([Date]) & [Qtr]

Qtr Rank = RANKX(all('Date'),'Date'[Qtr Year ],,ASC,Dense)

 

Measures like 

 

This Qtr = CALCULATE(sum('order'[Qty]), FILTER(ALL('Date'),'Date'[Qtr Rank]=max('Date'[Qtr Rank])))
Last Qtr = CALCULATE(sum('order'[Qty]), FILTER(ALL('Date'),'Date'[Qtr Rank]=max('Date'[Qtr Rank])-1))

 

YTD= CALCULATE(sum('order'[Qty]), FILTER(ALL('Date'),'Date'[Year]=max('Date'[Year]) && 'Date'[Month] <= Max('Date'[Qtr]) ))
LYTD = CALCULATE(sum('order'[Qty]), FILTER(ALL('Date'),'Date'[Year]=max('Date'[Year])-1 && 'Date'[Month] <= Max('Date'[Qtr])))

 

Make sure you have separate qtr year table 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.