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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Perturbed
Regular Visitor

Rolling 12 Month calculation error (using CALCULATE and DATESINPERIOD) using Excel's Power Pivot

Hello All,
Thanks for taking the time to help me.
I am trying to analyse my passive income using Excel's Power Pivot and I haven't been able to create a measure for "Income 12 Month Rolling Total".
Here's a Link to my sample Excel Spreadsheet in OneDrive@ https://1drv.ms/x/s!AjEQJC3O4N83iIQm2mI3-Yo-Kn2D4w?e=TiemTV

The source data I created by merging data (on date and income type) from a Net Worth report with data from a CashFlow report to create the (sample) source data as shown here.

ValueDate        Incometype   NetWorthValue Income
31/07/2021Interest186,285.27198.63
31/07/2021Pension303,571.432,752.05
31/07/2021Dividends564,213.924,589.82
31/08/2021Interest186,132.84432.91
31/08/2021Dividends576,622.910.00
31/08/2021Pension303,571.432,356.30
30/09/2021Dividends564,946.69663.62
30/09/2021Pension444,285.713,467.19
30/09/2021Interest43,331.39222.14
31/10/2021Interest49,353.25101.69
31/10/2021Pension444,285.713,862.95
31/10/2021Dividends577,708.348,780.32
30/11/2021Pension444,285.713,467.19
30/11/2021Interest88,953.99144.13
30/11/2021Dividends557,372.5941.41
31/12/2021Pension444,285.713,467.19
31/12/2021Interest89,188.07204.33
31/12/2021Dividends585,460.360.00
31/01/2022Dividends581,974.863,192.36
31/01/2022Pension444,285.713,862.95
31/01/2022Interest92,957.30224.65
28/02/2022Pension444,285.713,467.19
28/02/2022Interest92,043.12211.81
28/02/2022Dividends600,116.336.45
31/03/2022Pension446,428.573,455.22
31/03/2022Dividends607,747.1075.68
31/03/2022Interest86,767.79224.20
30/04/2022Pension446,428.573,873.01
30/04/2022Dividends589,216.814,321.29
30/04/2022Interest91,105.63242.58
31/05/2022Interest90,145.84256.05
31/05/2022Dividends586,059.53101.83
31/05/2022Pension446,428.573,514.11
30/06/2022Pension446,428.573,542.73
30/06/2022Interest76,212.84249.95
30/06/2022Dividends554,106.9851.48
31/07/2022Pension446,428.573,958.27
31/07/2022Interest82,027.54321.14
31/07/2022Dividends550,863.355,406.45

 

I loaded this table into the Excel Data Model. Then in the data model I created a date table ('Calendar') and added a relationship between the 'Calendar'[Date] and the Source Data[ValueDate].
"tblNWYieldbyDateByType [ValueDate] Many to One (*:1) << To tblNWYieldbyDateByType Calendar [Date]"

Then I created a new measure with the following DAX code.

12MonthIncome=CALCULATE(Sum([Income]),
(DATESINPERIOD('Calendar'[Date],
MAX('Calendar'[Date]),
-12, MONTH)))

Here is my sample Pivot Table showing that my 12MonthIncome measure;
1) Isn't creating a running total, only includes the value for current row.
2) Only reflects values from the current year. I don't want the running total to reset on Calendar changes like year-end.

(Apologies for the presentation. My copy-and-paste didn't work as desired. I have included a link to the Excel Spreadsheet near the top of this posting). The columns are date and then for each Income Type (Dividends, Interest, Pension) there are values for "Sum of Income" and "12 Month Income".

 

 Column Labels        Dividends Interest Pension Total Sum of IncomeTotal 12MonthIncomeDateSum of Income12MonthIncomeSum of Income12MonthIncomeSum of Income12MonthIncome  Grand Total35,37913,1563,8391,73064,26725,673103,48540,559
30/11/20204 114 2,284 2,402 
31/12/2020505 118 2,284 2,908 
31/01/20212,600 123 2,661 5,385 
28/02/202118 87 2,284 2,389 
31/03/20210 79 2,284 2,363 
30/04/20214,931 83 2,709 7,724 
31/05/202188 86 2,356 2,530 
30/06/20212 113 2,356 2,472 
31/07/20214,590 199 2,752 7,541 
31/08/20210 433 2,356 2,789 
30/09/2021664 222 3,467 4,353 
31/10/20218,780 102 3,863 12,745 
30/11/202141 144 3,467 3,653 
31/12/20210 204 3,467 3,672 
31/01/20223,1923,1922252253,8633,8637,2807,280
28/02/2022662122123,4673,4673,6853,685
31/03/202276762242243,4553,4553,7553,755
30/04/20224,3214,3212432433,8733,8738,4378,437
31/05/20221021022562563,5143,5143,8723,872
30/06/202251512502503,5433,5433,8443,844
31/07/20225,4065,4063213213,9583,9589,6869,686

 

Here is a mock-up of one sample Pivot Table I'm trying to achieve.-

 Column Labels        Dividends Interest Pension Total Sum of IncomeTotal 12MonthIncomeDateSum of Income12MonthIncomeSum of Income12MonthIncomeSum of Income12MonthIncome  Grand Total35,37913,1563,8391,73064,26725,673103,48540,559
         
         
30/11/20204 114 2,284 2,402 
31/12/2020505 118 2,284 2,908 
31/01/20212,600 123 2,661 5,385 
28/02/202118 87 2,284 2,389 
31/03/20210 79 2,284 2,363 
30/04/20214,931 83 2,709 7,724 
31/05/202188 86 2,356 2,530 
30/06/20212 113 2,356 2,472 
31/07/20214,590 199 2,752 7,541 
31/08/20210 433 2,356 2,789 
30/09/2021664 222 3,467 4,353 
31/10/20218,780 102 3,863 12,745 
30/11/202141 144 3,467 3,653 
31/12/20210 204 3,467 3,672 
31/01/20223,1923,1922252253,8633,8637,2807,280
28/02/2022662122123,4673,4673,6853,685
31/03/202276762242243,4553,4553,7553,755
30/04/20224,3214,3212432433,8733,8738,4378,437
31/05/20221021022562563,5143,5143,8723,872
30/06/202251512502503,5433,5433,8443,844
31/07/20225,4065,4063213213,9583,9589,6869,686
         

 

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

Hi @Perturbed ,

 

Based on your sample, I have changed the measure.

Please try:

12MonthIncome =
VAR _a =
    MAX ( 'tblNWYieldbyDateByType'[ValueDate] )
VAR _b =
    CALCULATE (
        SUM ( [Income] ),
        FILTER (
            ALLEXCEPT ( 'tblNWYieldbyDateByType', tblNWYieldbyDateByType[Incometype] ),
            [ValueDate] >= DATE ( 2020, 11, 1 )
                && [ValueDate] <= _a
                && [ValueDate] >= EOMONTH ( _a, -12 )
        )
    )
RETURN
    IF ( DATEDIFF ( DATE ( 2020, 11, 30 ), _a, MONTH ) >= 11, _b )

Output:

vjianbolimsft_0-1660725454015.png

Best Regards,

Jianbo Li

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

2 REPLIES 2
v-jianboli-msft
Community Support
Community Support

Hi @Perturbed ,

 

Based on your sample, I have changed the measure.

Please try:

12MonthIncome =
VAR _a =
    MAX ( 'tblNWYieldbyDateByType'[ValueDate] )
VAR _b =
    CALCULATE (
        SUM ( [Income] ),
        FILTER (
            ALLEXCEPT ( 'tblNWYieldbyDateByType', tblNWYieldbyDateByType[Incometype] ),
            [ValueDate] >= DATE ( 2020, 11, 1 )
                && [ValueDate] <= _a
                && [ValueDate] >= EOMONTH ( _a, -12 )
        )
    )
RETURN
    IF ( DATEDIFF ( DATE ( 2020, 11, 30 ), _a, MONTH ) >= 11, _b )

Output:

vjianbolimsft_0-1660725454015.png

Best Regards,

Jianbo Li

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

Thanks very much Jianbo Li, 

This is the help I was looking for: The "tips & tricks" that really helped were

- Use the "AllExcept" function to prevent filtering on the field, [IncomeType], that I want to summarise on.

- Use simple date comparisons rather than the built-in Time Period function DATESBETWEEN

So as not to lose the point of where I was struggling, I copied and pasted only the last portion of my data. I had to tweak your code to go all the way back to my first records that were filtered out. Here's the code I'm going to use to include all of my data

 

VAR EndDate = MAX ( tblNWYieldbyDateByType[ValueDate] )  /* Until the end of my records */
VAR StartDate = DATE( 2009, 01,01)			/* Any Date before my first record */
VAR IncomeSUM =

	CALCULATE ( SUM(tblNWYieldbyDateByType[Income] ), 
	FILTER(
		ALLEXCEPT ( tblNWYieldbyDateByType,tblNWYieldbyDateByType[Incometype] ) ,
		[ValueDate] >= StartDate
		&& [ValueDate] <= EndDate
		&& [ValueDate] >= EOMONTH ( EndDate, -11 )
		)
	) /* End of Calculate function */
	RETURN
	IF ( DATEDIFF ( StartDate, EndDate, MONTH) >= 11, IncomeSUM)

Thank you😊

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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