cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mckinney10 Frequent Visitor
Frequent Visitor

YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

I've been trying to get YTD measures to compare the current YTD against last year and 2 years ago YTDs.  I was able to get the current YTD, but have been having trouble with the other two.  2016 is made up of 14 months and goes from Nov 2015 through Dec 2016 and 2015 starts on Nov 2014 through Oct 2015.  

 

I have a table with account data that has dates and sales.  I have also created a calendar table with dates, months, years etc. that's linked to the sales table. I have the following measures:

 

Total Sales = SUM(Sales[Sales])

CY YTD = TOTALYYTD([Total Sales], Sales[Date]) 

 

When I try to get LY YTD, I can't seem to get the amounts from Nov and Dec 2015 to be included.  How can I get the time intelligence functions to adjust to these particular years?  Thanks for your time and help.  

 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
CheenuSing Super Contributor
Super Contributor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10,

 

I downloaded the YTD_test pbix sent by you.

 

The approach I had taken is as under.

 

1.  I changed your Dates table formation as  -  Dates = CALENDAR(MIN(Sales[Date]), MAX(Sales[Date]))

     This is the best way to create a calendar table based on the minimum and maximum date of the fact tables.

 

2.  Created a column called MonthNumber = Month(Dates[Date])

3.  Set the MonthName to sorted by column MonthNumber.

4.  Created a MonthSequentialNumber column

     MonthSequentialNumber = ('Dates'[Year] - MIN( 'Dates'[Year] )) * 12 + 'Dates'[MonthNumber]

    This generates a sequential number for each month and incremented by 1 for every month in the Dates table.

    In the sample file this number ranges from 11 to 45.

    To go back 1 year just need to subtract 12 from this. Similarly to go back 2 years subtract by 24 and so on.

 

5.  Created a measure called

     YTD1YearB4 = Calculate([Total Sales],Filter(ALL(Dates), Dates[Year] = Max(Dates[Year]) - 1  && Dates 

                                          [MonthSequentialNumber] <= Max(Dates[MonthSequentialNumber]) - 12) )

 

6. Created a measure called

    YTD2YearB4 = Calculate([Total Sales],Filter(ALL(Dates), Dates[Year] = Max(Dates[Year]) - 2  && Dates

                                                    [MonthSequentialNumber] <= Max(Dates[MonthSequentialNumber]) - 24) )

 

Depending on the Year selected it will report the 1year before and 2 year before total sales.

 

I have  uploaded the file in one drive. and the link is

 

https://1drv.ms/u/s!ApP3mBZyGaHfzyeQc9QxgrROjsFD

 

If this works for you please accept this as a solution and also give KUDOS.

 

Cheers

 

CheenuSing

 

Did I answer your question? Mark my post as a solution and also give KUDOS !

Proud to be a Datanaut!
9 REPLIES 9
Super User
Super User

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10,

 

Try to do something like this for previous year:

 

LY YTD =
TOTALYTD (
    [Total Sales],
    DATESBETWEEN ( Sales[Date], DATE ( 2015, 11, 01 ), DATE ( 2016, 12, 31 ) )
)

You need to adjust the date part to be affect by your slicers but without further information regarding the tipe of slice and dice you wan to do I can't give you a better explanation.

 

Regards,

MFelix

 



Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!




mckinney10 Frequent Visitor
Frequent Visitor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

@MFelix Thanks for the response. 

 

I'm looking to compare last year and 2 years prior to the current year's YTD.   So for 2016, the two extra months (Nov and Dec 2015) plus all the months up to September.  I tried your suggested measure, but I wasn't able to get it to work correctly.  After more searching and trial and error, I was able to get the correct YTD amounts for 2016 with the following measure: 

 

LY YTD =
VAR MaxDate =
               CALCULATE ( MAX ( Sales[Date] ), ALL ( Sales ) )
RETURN
               CALCULATE (
                              [LY Total],
                              SAMEPERIODLASTYEAR (
                                  INTERSECT (
                                  VALUES ( Dates[Date] ),
                                  DATESBETWEEN ( Dates[Date].[Date], BLANK (), MaxDate ))))

 

Where [LY Total] is the total sales amount for 2016.  Now, I'm having trouble with 2 years prior YTD.  I'm just getting the total amounts for the entire year 2015 instead of the YTD.   I haven't been successful in getting the right dates filter.  I'd like it to look something like this

 

Test.PNG

 

CheenuSing Super Contributor
Super Contributor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10

 

Couple of questions.

 

1. Just like the measure [LY Total] have you calculated any measure for 2 years total.

2. Do you have a calendar table and linked with your Sales Fact table.

3. Going forward what is your financial year. Will it be from Nov to Oct in the future.

 

I feel you will have to write specific YTD totals for the years 2016 and 2015 as they do not fall under the same financial period.

 

If you can share the pbix please load it on one drive and provide the link here to formulate a solution.

 

Cheers

 

CheenuSing

Did I answer your question? Mark my post as a solution and also give KUDOS !

Proud to be a Datanaut!
Moderator v-qiuyu-msft
Moderator

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10,

 

You can try to create a measure like below: 

 

L2Y  = CALCULATE(SUM(Sales[Amount]),DATEADD(DATESYTD('Dates'[Date]),-2,YEAR))

 

If it doesn't work, please share the pbix file with dummy data for us to test. 

 

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.
hemantsingh Member
Member

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10,

 

   did you get any solution to this??? If yes then kindly share.

 

Regards,

Hemant

mckinney10 Frequent Visitor
Frequent Visitor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @CheenuSing@v-qiuyu-msft

 

Thanks for your reply.  Yes, I have created a measure for the total from 2 years ago and created a calendar table that's linked to the Sales table.  This year's financial year will match the calendar year (Jan - Dec).  

 

Here's a link to a test pbix 

 

 

CheenuSing Super Contributor
Super Contributor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10,

 

 

A quick question.  Your financial years are different for each year. Nov - Oct 2015 (12 Months),  Nov-Dec 16 (14 Months) and Jan-Dec 2017.

 

For Profit & Loss, Balance Sheet one may have to consolidate the 12 monhts, 14 months and so on for different financial years.


For Sales Reporting , when the current year is reproted for Jan - Sep 2017 - for 9 months. It would be wrong to compare Nov2015 to Sep 2016 which would be 11 months.  One should compare the same number of months in the previous year Jan-Sep 16.

Likewise for Jan-Sep 2015.  Otherwise comparisons reflect different number of months.

 

Please clarify.

 

Cheers

 

CheenuSing

 

Did I answer your question? Mark my post as a solution and also give KUDOS !

Proud to be a Datanaut!
mckinney10 Frequent Visitor
Frequent Visitor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

@CheenuSing

 

How would you go about cutting down the months and getting the ytd numbers? Also,  could you explain how this 

 

LY YTD =
VAR MaxDate =
               CALCULATE ( MAX ( Sales[Date] ), ALL ( Sales ) )
RETURN
               CALCULATE (
                              [LY Total],
                              SAMEPERIODLASTYEAR (
                                  INTERSECT (
                                  VALUES ( Dates[Date] ),
                                  DATESBETWEEN ( Dates[Date].[Date], BLANK (), MaxDate ))))

works with the 14 month year and is it possible to manipulate this to work with 2 years back? 

Highlighted
CheenuSing Super Contributor
Super Contributor

Re: YTD Comparisons of Current, Last Year and 2 Years Prior with Irregular Calendar Years

Hi @mckinney10,

 

I downloaded the YTD_test pbix sent by you.

 

The approach I had taken is as under.

 

1.  I changed your Dates table formation as  -  Dates = CALENDAR(MIN(Sales[Date]), MAX(Sales[Date]))

     This is the best way to create a calendar table based on the minimum and maximum date of the fact tables.

 

2.  Created a column called MonthNumber = Month(Dates[Date])

3.  Set the MonthName to sorted by column MonthNumber.

4.  Created a MonthSequentialNumber column

     MonthSequentialNumber = ('Dates'[Year] - MIN( 'Dates'[Year] )) * 12 + 'Dates'[MonthNumber]

    This generates a sequential number for each month and incremented by 1 for every month in the Dates table.

    In the sample file this number ranges from 11 to 45.

    To go back 1 year just need to subtract 12 from this. Similarly to go back 2 years subtract by 24 and so on.

 

5.  Created a measure called

     YTD1YearB4 = Calculate([Total Sales],Filter(ALL(Dates), Dates[Year] = Max(Dates[Year]) - 1  && Dates 

                                          [MonthSequentialNumber] <= Max(Dates[MonthSequentialNumber]) - 12) )

 

6. Created a measure called

    YTD2YearB4 = Calculate([Total Sales],Filter(ALL(Dates), Dates[Year] = Max(Dates[Year]) - 2  && Dates

                                                    [MonthSequentialNumber] <= Max(Dates[MonthSequentialNumber]) - 24) )

 

Depending on the Year selected it will report the 1year before and 2 year before total sales.

 

I have  uploaded the file in one drive. and the link is

 

https://1drv.ms/u/s!ApP3mBZyGaHfzyeQc9QxgrROjsFD

 

If this works for you please accept this as a solution and also give KUDOS.

 

Cheers

 

CheenuSing

 

Did I answer your question? Mark my post as a solution and also give KUDOS !

Proud to be a Datanaut!

Helpful resources

Announcements
Community Highlights

Community Highlights

Find out what's new in the Power BI Community!

Summit North America

Power Platform Summit North America

Register by September 5 to save $200

Virtual Launch Event

Microsoft Business Applications Virtual Launch Event

Watch the event on demand for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

MBAS Gallery

Watch Sessions On Demand!

Continue your learning in our online communities.

Users Online
Currently online: 396 members 3,933 guests
Please welcome our newest community members: