cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
bwelsh Regular Visitor
Regular Visitor

Adding Pay Period to Date Dimension Table

Hello,

 

I have a date dimension table and I need to add a column for pay period end date each date in the table ends on. How would I go about doing this? Generally (in excel) I would set the first static pay period end date and simply count up from there, however this date dimension table is dynamic so I wont be able to do that. Our last bi-weekly pay period ended on April 28th.

1 ACCEPTED SOLUTION

Accepted Solutions
Moderator v-sihou-msft
Moderator

Re: Adding Pay Period to Date Dimension Table

@bwelsh

 

In this scenario, you can create a calculated column to display the pay period number based on the first pay period start date. Then you can calculate the max date within same pay period group.

 

I use 2017/4/29 as the first pay period start date.

 

1. Create a calculated column like below;

 

pay period number = FLOOR(DATEDIFF(DATE(2017,4,29),'Table'[Date],DAY)/14,1)+1

5.PNG

 

 

2. Then create a column to get the pay period end date.

 

pay period end date = CALCULATE(MAX('Table'[Date]),ALLEXCEPT('Table','Table'[pay period number]))

6.PNG

 

 

Regards,

3 REPLIES 3
Pfister Established Member
Established Member

Re: Adding Pay Period to Date Dimension Table

Hi @bwelsh

Can you post a pic of your data and a pic of the desired output?

 

Greetings Hp Pfister
Power Query Buch online auf http://www.powerbi-pro.com
bwelsh Regular Visitor
Regular Visitor

Re: Adding Pay Period to Date Dimension Table

This is my date dimension table. I need to create a column (based on the first column) that shows the last date of the pay-period.

 

Capture.PNG

Moderator v-sihou-msft
Moderator

Re: Adding Pay Period to Date Dimension Table

@bwelsh

 

In this scenario, you can create a calculated column to display the pay period number based on the first pay period start date. Then you can calculate the max date within same pay period group.

 

I use 2017/4/29 as the first pay period start date.

 

1. Create a calculated column like below;

 

pay period number = FLOOR(DATEDIFF(DATE(2017,4,29),'Table'[Date],DAY)/14,1)+1

5.PNG

 

 

2. Then create a column to get the pay period end date.

 

pay period end date = CALCULATE(MAX('Table'[Date]),ALLEXCEPT('Table','Table'[pay period number]))

6.PNG

 

 

Regards,