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

Custom Financial Year

Hi,

 

Our financial year runs from Jun 1st to May 31st is there an 'easy' way to create a new column in the calendar table which has the relvent year against the date.

 

 

In our nominal detail table it has financial year.  What would be the best way to get 

 

Year to Date

Same period Last year

Variance against last year

 

An example of previous year variance is

 

Previous Year Test = CALCULATE(sum('public nomhead'[nominal]),'public nomdet'[nom_year] = ('public nomdet'[nom_year] -1))
 
The above doesnt work though... all help appreciated.

 

 

 

 

Thanks

 

Chris

1 ACCEPTED SOLUTION
Stachu
Community Champion
Community Champion

you can specify custom financial year in the calculation
https://docs.microsoft.com/en-us/dax/datesytd-function-dax
you will need custom column in your calendar table

FinancialYear = 
VAR __month = MONTH('Calendar'[Date])
VAR __year = YEAR('Calendar'[Date])
RETURN
IF(__month<6, __year-1 & "/" &__year, __year & "/" & __year+1)

SAMEPERIODLASTYEAR will work fine whenever you select year from this

as for YTD, you can use DATESYTD, e.g.

YTD = 
CALCULATE(
    SUM('public nomhead'[nominal]), 
    DATESYTD(Calendar[Date], "31-05")
)

for PY YTD you can just use SAMEPERIODLASTYEAR within calculate that uses the [YTD] measure

 



Did I answer your question? Mark my post as a solution!
Thank you for the kudos 🙂

View solution in original post

4 REPLIES 4
Stachu
Community Champion
Community Champion

you can specify custom financial year in the calculation
https://docs.microsoft.com/en-us/dax/datesytd-function-dax
you will need custom column in your calendar table

FinancialYear = 
VAR __month = MONTH('Calendar'[Date])
VAR __year = YEAR('Calendar'[Date])
RETURN
IF(__month<6, __year-1 & "/" &__year, __year & "/" & __year+1)

SAMEPERIODLASTYEAR will work fine whenever you select year from this

as for YTD, you can use DATESYTD, e.g.

YTD = 
CALCULATE(
    SUM('public nomhead'[nominal]), 
    DATESYTD(Calendar[Date], "31-05")
)

for PY YTD you can just use SAMEPERIODLASTYEAR within calculate that uses the [YTD] measure

 



Did I answer your question? Mark my post as a solution!
Thank you for the kudos 🙂

Anonymous
Not applicable

Thanks @Stachu

 

All works great Apart from previous year to date.

 

I have

 

Debit YTD prev year = CALCULATE(sum('public nomdet'[debit]),SAMEPERIODLASTYEAR(DATESYTD('Calendar'[Date],"05/31")))

Example

 

in 2018/2019 it only seems to do the year to date where there is a value in 2018/2019 rather than the months where are no values but values in 2017/2018

 

Example.PNG

 

 

 

Anonymous
Not applicable

I set the direction in the relatio bship betwen the calendar and fact table as one way as per other forum post and it seems to work.

 

Strange... would be useful to know why

Stachu
Community Champion
Community Champion

I always try to keep them with single direction as it makes DAX more predictable, here is some explanation on bidirectional relationships in general
https://www.sqlbi.com/articles/bidirectional-relationships-and-ambiguity-in-dax/

 



Did I answer your question? Mark my post as a solution!
Thank you for the 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.

Top Solution Authors