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
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:
| EmployeeID | EmploymentCommencedDate | EmploymentTerminatedDate |
| 400 | 12/3/2017 | 9/30/2020 |
| 401 | 10/3/2019 | 1/5/2021 |
Here is what I want to have:
| EmployeeID | EmploymentCommencedDate | EmploymentTerminatedDate | YearEnd |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2017 |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2018 |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2019 |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2020 |
| 401 | 10/3/2019 | 1/5/2021 | 12/31/2019 |
| 401 | 10/3/2019 | 1/5/2021 | 12/31/2020 |
| 401 | 10/3/2019 | 1/5/2021 | 12/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
| EmployeeID | EmploymentCommencedDate | EmploymentTerminatedDate | YearEndDate | Tenure |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2017 | 0 |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2018 | 1 |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2019 | 2 |
| 400 | 12/3/2017 | 9/30/2020 | 12/31/2020 | 3 |
| 401 | 10/3/2019 | 1/5/2021 | 12/31/2019 | 0 |
| 401 | 10/3/2019 | 1/5/2021 | 12/31/2020 | 1 |
| 401 | 10/3/2019 | 1/5/2021 | 12/31/2021 | 2 |
Solved! Go to Solution.
Hi,
Please check the below picture and the attached pbix file.
It is for creating a new table by DAX.
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] )
)
)
Hi,
Please check the below picture and the attached pbix file.
It is for creating a new table by DAX.
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] )
)
)
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 19 | |
| 13 | |
| 8 | |
| 4 | |
| 4 |
| User | Count |
|---|---|
| 29 | |
| 21 | |
| 17 | |
| 11 | |
| 10 |