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
AnilKumar
Helper II
Helper II

Running Totals with Financial Year

Hi all,

 

I have the requirement to achieve the running totals w.r.t to year/date and name as like below snap.

Running TTls.png

 Here totally 3 Financial Years. for Name1, there is no records in 21-22 so 20-21 balance is just transfered to 21-22. in the same way, for name2, no recs in 20-21 FY so 19-20FY amt is transfer ed to 20-21FY. 

Anyone please help me out.

 

Thanks in advance,

Vishnu Priya

2 ACCEPTED SOLUTIONS
v-qiuyu-msft
Community Support
Community Support

Hi @AnilKumar

 

From your description, fiscal year starts from April 1st, so date "01-01-2019" should belong to fiscal year 18-19 instead of 19-20. 

 

For your requirement, you can create a calendar table, then create fiscal year column both in fact table and calendar table, drag fiscal year column from calendar table to matrix column bucket. Then create a measure below: 

 

Measure 2 = CALCULATE(SUM('Table'[Amt]),FILTER(ALL('Table'),'Table'[FiscalYear]<=MAX('Calendar'[FiscalYear])&&'Table'[Name]=MAX('Table'[Name])))
 
q1.PNG
 
Best Regards,
Qiuyun Yu
Community Support Team _ Qiuyun Yu
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

amitchandak
Super User
Super User

@AnilKumar , The only thing which changes here is your date calendar. You can have date cumulative working

Have a calendar like

https://www.dropbox.com/s/wrcyk5j66corvjg/Apr2Mar-Cal.pbix?dl=0

Join date calendar date with your date and formula like this will work

Cumm Sales = CALCULATE(SUM(Sales[Sales Amount]),filter(date,date[date] <=maxx(date,date[date])))
Cumm Sales = CALCULATE(SUM(Sales[Sales Amount]),filter(date,date[date] <=max(Sales[Sales Date])))

 

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 :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.

 

View solution in original post

2 REPLIES 2
amitchandak
Super User
Super User

@AnilKumar , The only thing which changes here is your date calendar. You can have date cumulative working

Have a calendar like

https://www.dropbox.com/s/wrcyk5j66corvjg/Apr2Mar-Cal.pbix?dl=0

Join date calendar date with your date and formula like this will work

Cumm Sales = CALCULATE(SUM(Sales[Sales Amount]),filter(date,date[date] <=maxx(date,date[date])))
Cumm Sales = CALCULATE(SUM(Sales[Sales Amount]),filter(date,date[date] <=max(Sales[Sales Date])))

 

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 :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.

 

v-qiuyu-msft
Community Support
Community Support

Hi @AnilKumar

 

From your description, fiscal year starts from April 1st, so date "01-01-2019" should belong to fiscal year 18-19 instead of 19-20. 

 

For your requirement, you can create a calendar table, then create fiscal year column both in fact table and calendar table, drag fiscal year column from calendar table to matrix column bucket. Then create a measure below: 

 

Measure 2 = CALCULATE(SUM('Table'[Amt]),FILTER(ALL('Table'),'Table'[FiscalYear]<=MAX('Calendar'[FiscalYear])&&'Table'[Name]=MAX('Table'[Name])))
 
q1.PNG
 
Best Regards,
Qiuyun Yu
Community Support Team _ Qiuyun Yu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.