Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hello,
I have a Date table and I want to create a calculated column that gives me the date of the previous year. For example, if the date is 1/1/2018 the LY column should be 1/1/2017. Are there any DAX functions that will accomplish this? When I use SAMEPERIODLASTYEAR or DATEADD, it returns a table, so it won't work with a calculated column. Also, if there is a function, how would it handle the leap year? What would the previous year column look like for 2/29/2016?
Thanks.
Solved! Go to Solution.
HI @vega
Try this Column.
For 29 Feb 2016 it will give 1 Mar 2015
LY Date = DATE ( YEAR ( DateTable[Date] ) - 1, MONTH ( DateTable[Date] ), DAY ( DateTable[Date] ) )
Hi @vega,
Based on my understanding, if this year is the leap year, the previous year column should display blank. For example the previous year of 2/29/2016 day is blank, because there is no 2/29/2015. Please create a calculated column using the formula.
LY Date_Edit =
IF (
MONTH ( DateTable[Date] ) = 2
&& DAY ( DateTable[Date] ) = 29,
BLANK (),
DATE ( YEAR ( DateTable[Date] ) - 1, MONTH ( DateTable[Date] ), DAY ( DateTable[Date] ) )
)
Best Reards,
Angelia
Hi @vega,
Based on my understanding, if this year is the leap year, the previous year column should display blank. For example the previous year of 2/29/2016 day is blank, because there is no 2/29/2015. Please create a calculated column using the formula.
LY Date_Edit =
IF (
MONTH ( DateTable[Date] ) = 2
&& DAY ( DateTable[Date] ) = 29,
BLANK (),
DATE ( YEAR ( DateTable[Date] ) - 1, MONTH ( DateTable[Date] ), DAY ( DateTable[Date] ) )
)
Best Reards,
Angelia
HI @vega
Try this Column.
For 29 Feb 2016 it will give 1 Mar 2015
LY Date = DATE ( YEAR ( DateTable[Date] ) - 1, MONTH ( DateTable[Date] ), DAY ( DateTable[Date] ) )
Hi @Zubair_Muhammad,
This works very well as a calculated column. I was wondering if this can also be used as a measure?
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 38 | |
| 36 | |
| 33 | |
| 32 | |
| 29 |
| User | Count |
|---|---|
| 129 | |
| 88 | |
| 79 | |
| 68 | |
| 63 |