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

Create a custom column that generates rows for every year between two dates

I have tried to create a custom column that generates a row for every year in between two dates. I have applied a query that produces this by the day but I need year instead.

 

Here is the query for days that I need to adapt for years:

List.Dates([EmploymentCommencedDate], Duration.Days ([EmploymentTerminatedDate]-[Column1.EmploymentCommencedDate]), #duration (1,0,0,0))

 

Here is an example of my table before:

EmployeeIDEmploymentCommencedDateEmploymentTerminatedDate
40012/3/20179/30/2020
40110/3/20191/5/2021

 

Here is what I want to have:

EmployeeIDEmploymentCommencedDateEmploymentTerminatedDateYearEnd
40012/3/20179/30/202012/31/2017
40012/3/20179/30/202012/31/2018
40012/3/20179/30/202012/31/2019
40012/3/20179/30/202012/31/2020
40110/3/20191/5/202112/31/2019
40110/3/20191/5/202112/31/2020
40110/3/20191/5/202112/31/2021

 

Once I have this, I will calculate the duration of time of employment in years (Tenure) but the difference of the YearEndDate - EmploymentCommencedDate

EmployeeIDEmploymentCommencedDateEmploymentTerminatedDateYearEndDateTenure
40012/3/20179/30/202012/31/20170
40012/3/20179/30/202012/31/20181
40012/3/20179/30/202012/31/20192
40012/3/20179/30/202012/31/20203
40110/3/20191/5/202112/31/20190
40110/3/20191/5/202112/31/20201
40110/3/20191/5/202112/31/20212

 

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

It is for creating a new table by DAX.

 

Jihwan_Kim_0-1680928613067.png

 

 

New table create by DAX = 
VAR _employeetable = Employee
VAR _mindateyear =
    YEAR ( MIN ( Employee[EmploymentCommencedDate] ) )
VAR _maxdateyear =
    YEAR ( MAX ( Employee[EmploymentTerminatedDate] ) )
VAR _calendartable =
    CALENDAR ( DATE ( _mindateyear, 1, 1 ), DATE ( _maxdateyear, 12, 31 ) )
VAR _endofyear =
    SUMMARIZE (
        ADDCOLUMNS (
            _calendartable,
            "@yearenddate",
                MAXX (
                    FILTER ( _calendartable, YEAR ( [Date] ) = YEAR ( EARLIER ( [Date] ) ) ),
                    [Date]
                )
        ),
        [@yearenddate]
    )
RETURN
    GENERATE (
        _employeetable,
        FILTER (
            _endofyear,
            YEAR ( [@yearenddate] ) >= YEAR ( Employee[EmploymentCommencedDate] )
                && YEAR ( [@yearenddate] ) <= YEAR ( Employee[EmploymentTerminatedDate] )
        )
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

View solution in original post

1 REPLY 1
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

It is for creating a new table by DAX.

 

Jihwan_Kim_0-1680928613067.png

 

 

New table create by DAX = 
VAR _employeetable = Employee
VAR _mindateyear =
    YEAR ( MIN ( Employee[EmploymentCommencedDate] ) )
VAR _maxdateyear =
    YEAR ( MAX ( Employee[EmploymentTerminatedDate] ) )
VAR _calendartable =
    CALENDAR ( DATE ( _mindateyear, 1, 1 ), DATE ( _maxdateyear, 12, 31 ) )
VAR _endofyear =
    SUMMARIZE (
        ADDCOLUMNS (
            _calendartable,
            "@yearenddate",
                MAXX (
                    FILTER ( _calendartable, YEAR ( [Date] ) = YEAR ( EARLIER ( [Date] ) ) ),
                    [Date]
                )
        ),
        [@yearenddate]
    )
RETURN
    GENERATE (
        _employeetable,
        FILTER (
            _endofyear,
            YEAR ( [@yearenddate] ) >= YEAR ( Employee[EmploymentCommencedDate] )
                && YEAR ( [@yearenddate] ) <= YEAR ( Employee[EmploymentTerminatedDate] )
        )
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

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.