Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi all,
This came up as I was trying to answer this post by @hbolo (no need to read it to answer this question). Here is the pbix
We have a Date table with dates between 01/01/2018 and today (Jan 3rd, 2019).
We place Date[Date] (down to the day level) in the rows of a matrix visual and these two measures in values:
YTDPreviousYearRevenue =
CALCULATE (
SUM ( Revenue[Revenue] );
SAMEPERIODLASTYEAR ( DATESYTD ( 'Date Table'[Date] ) )
)
YTDPreviousYearRevenue_2 = CALCULATE ( SUM ( Revenue[Revenue] ); DATESYTD ( SAMEPERIODLASTYEAR ( 'Date Table'[Date] ) ) )
where we are simply calculating the YTD revenue for the previous year.
For January 3rd, 2019 (the last day on the Date table),
[YTDPreviousYearRevenue_ 2] yields the correct result (i.e. the revenue for 1-3 Jan 2018).
However, [YTDPreviousYearRevenue] yields an incorrect result: the revenue for 1-31 Jan 2018. [YTDPreviousYearRevenue] is thus considering the full month of January 2018 while the YTD of 2019 is only 1-3 Jan, the first 3 days I would expect both measures to yield the exact same result.
Note that [YTDPreviousYearRevenue] yields the correct result for the 1st and 2nd Jan 2019. The only issue seems to be on the 3rd Jan 2019, the last day on the Date table.
Does anybody know what is going on?
Many thanks for your help
Note: I suspect it has to do with the Date table finishing on Jan 3rd, 2019 but do not know why. If the Date table is extended to include dates up to the end of 2019 this problem disappears.
Solved! Go to Solution.
This is just another case where the Time Intelligence functions don't work as expected because the Date table is wrong.
Remember: Time Intelligence functions are guaranteed to work *only* if the Date table is "complete" - meaning you need all the dates until the end of the year.
Not doing that, what happens is that the year 2019 seems made by 15 days, so if you include all of them than it seems you have an entire month, or an entire year.... You are violating the assumption made by Time Intelligence and you cannot trust any result at that point.
@AlB @v-lili6-msft @marcorusso @Greg_Deckler @MFelix
I am encountering a similiar problem with my data set at the moment, and both of the formulas (attached) here are resulting a value that is until end of month, rather than (ie today up to 08/05/19). I am not sure if the reason for this is that i am using a relationship to connect my data table to a calendar table, as my data is not contiguous, so results in an error when a date slicer is used...
I am using
and i am getting the correct result, however it is quite ugly and seems to have some bugs,
ie. if i change the date range to all of 2018, it outputs a value that is the sum of 2018 and 2019 to date..
Do you know of any other formulas that work for calculating sum of same period last year to the current date?
I want to be able to create some extra graphs from this and a better formula would be helpful
YTDPreviousYearRevenue =
CALCULATE (
SUM ( Revenue[Revenue] );
SAMEPERIODLASTYEAR ( DATESYTD ( 'Date Table'[Date] ) )
)
YTDPreviousYearRevenue_2 = CALCULATE ( SUM ( Revenue[Revenue] ); DATESYTD ( SAMEPERIODLASTYEAR ( 'Date Table'[Date] ) ) )
If you select one month in the Date table, you get the entire month. In the comparison with the previous period you might want to reduce this so you should follow the advices described in this article:
https://www.sqlbi.com/articles/hiding-future-dates-for-calculations-in-dax/
hi, @AlB
Unfortunately, So far I haven't got any reply about this question.
and I read these in the book The Definitive Guide to DAX: Business intelligence with Microsoft Excel, SQL Server Analysis Service... by Marco Russo and Alberto Ferrari.
in page 173:
The following two definitions of PY YTD Sales are equivalent, even if the second one could be slightly faster (but barely measureable).
and in your case, date table is from "2018,1,1" to today, you may try this formula
Date Table = ADDCOLUMNS ( CALENDAR (DATE(2018,1,1), DATE(YEAR(TODAY()),12,31)), "Year", YEAR ( [Date]), "Month Name", FORMAT ( [Date], "mmmm" ), "Monthnumber", FORMAT ( [Date], "MM" ) )
add a judge column for date table
judge = IF('Date Table'[Date]<=TODAY(),1,2)
Then add it to report level filter and set it "1"
Result:
This is just as a reference, I also think reason for this case is that date table is incomplete.
Best Regards,
Lin
I would think that @marcorusso might like to dig into this one. All I can say is this is the kind of reason that I creaed the Time Intelligence The Hard Way Quick Measure:
The time intelligence functions are just these mysterious little black boxes that just act downright weird at times. I frankly don't really trust them as far as I can try catch throw them.
This is just another case where the Time Intelligence functions don't work as expected because the Date table is wrong.
Remember: Time Intelligence functions are guaranteed to work *only* if the Date table is "complete" - meaning you need all the dates until the end of the year.
Not doing that, what happens is that the year 2019 seems made by 15 days, so if you include all of them than it seems you have an entire month, or an entire year.... You are violating the assumption made by Time Intelligence and you cannot trust any result at that point.
Thanks @Greg_Deckler
Yeah, I don't like them much either. They kinda shady. Let's see if @marcorusso can enlighten us then, as usual.
I would give you kudos but it's not working , just like a bunch of other features lately on this site.
@AlB - Try clearing your browser cache, that worked for me to clear up all the issues.
I tried that, even the clering the whole history, but nothing changes. I'm told they are trying to fix it.
@AlB - Clear your browser cache, that worked for me to clear up all the issues.
Perhaps very knowledgeable people like @Zubair_Muhammad, @Greg_Deckler, @MFelix would care to chip in?
Many thanks
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em Português
Very interesting
I remember you found a bug before as well
I am not sure why this is happening
but if we use following we get correct results even with the last date.
YTDPreviousYearRevenue = CALCULATE ( SUM ( Revenue[Revenue] ), SAMEPERIODLASTYEAR ( DATESYTD ( 'Date Table'[Date].[Date]) ) )
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsThanks very much @Zubair_Muhammad
It gets more and more intriguing. Let's see what the others say.
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
111 | |
105 | |
105 | |
88 | |
61 |
User | Count |
---|---|
165 | |
133 | |
132 | |
95 | |
86 |