Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
vega
Resolver III
Resolver III

Calculated Column Last Year Date

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.

2 ACCEPTED SOLUTIONS
Zubair_Muhammad
Community Champion
Community Champion

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] ) )

View solution in original post

v-huizhn-msft
Microsoft Employee
Microsoft Employee

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

View solution in original post

3 REPLIES 3
v-huizhn-msft
Microsoft Employee
Microsoft Employee

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

Zubair_Muhammad
Community Champion
Community Champion

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] ) )
Anonymous
Not applicable

Hi @Zubair_Muhammad,

This works very well as a calculated column. I was wondering if this can also be used as a measure?

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.