cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
AndyTrezise Helper II
Helper II

Rank table over 3 different months

I have a table which contains employee utilisation over the course of the year - something like this:

 

EmployeeYearMonthUtilisation
E12017175%
E12017273%
E12017378%
E12017464%
E12017580%
E12017679%
E22017166%
E22017269%
E22017379%
E22017475%
E22017578%
E22017679%
E32017174%
E32017275%
E32017379%
E32017484%
E32017582%
E32017681%

 

I woud like to use two slicers to select year / month and then display three tables of results showing employees ranked by their utilisation in current, previous and previous-1 months.

 

So, if I select 2017 / 5 I want to see:

 

Current Period (2017/5)

1 E3 82%

2 E1 80%

3 E2 78%

 

Previous Period (2017/4)

1 E3 84%

2 E2 75%

3 E1 64%

 

Previous -1 Period (2017/3)

1 E3 79%

2 E2 79%

3 E1 78%

 

Average over Last 3 Periods

1 E3 81.66%

2 E2 77.33%

3 E1 74%

 

I thought I could just create a simple measure:

 

Rank = RANKX(ALLSELECTED(UTILISATION),CALCULATE(SUM(UTILISATION[Utilisation])))

 

And then filter each visual on a month / year basis but a) this is not very dynamic and I will need to manually select the month numbers for each period and b) I also found that the ranking for the average over the 3 periods all returned number 1. So I think I'm going about it the wrong way.

 

I need to:

 

1. determine from the slicer the year / month selected and then rank only the rows that match the same period

2. do the same for previous periods

3 average and rank over the 3 periods (i.e. return 1 row / result for each employee).

 

Any help would be greatly appreciated.

1 ACCEPTED SOLUTION

Accepted Solutions
Moderator v-yuezhe-msft
Moderator

Re: Rank table over 3 different months

@AndyTrezise,

This is a calculated column but not a measure, it calculates rank of utilisation of same year and same Month, which achieves your requirement.

Regards,
Lydia

Community Support Team _ Lydia Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
Moderator v-yuezhe-msft
Moderator

Re: Rank table over 3 different months

@AndyTrezise,

1.Create Year table containing year values(2016,2017…), create Month table containing month values(1,2,3…12). Please note that there is no relationship among the three tables(Year, Month and UTILISATION table).
2.JPG


1.JPG

2. Create the following calculated columns in the UTILISATION table.

Date = DATE(UTILISATION[Year],UTILISATION[Month],1)

 

RankColumn = RANKX(FILTER(UTILISATION,UTILISATION[Year]=EARLIER(UTILISATION[Year])&&UTILISATION[Month]=EARLIER(UTILISATION[Month])),UTILISATION[Utilisation],,DESC,Dense)


3. Create the following measures in UTILISATION table.

checkmonth = 
var Ldate = date(max('Year'[Year]),max('Month'[Month]),1) //Last date

var Fdate = EDATE(Ldate,-2) //First date

return

 if(min('UTILISATION'[Date])<fdate,
         blank(),
         if(min('UTILISATION'[Date])>Ldate,
                   blank(),
                   1))

 

Average = 
var Ldate = date(max('Year'[Year]),max('Month'[Month]),1) //Last date

var Fdate = EDATE(Ldate,-2) //First date

return

 (CALCULATE(SUM(UTILISATION[Utilisation]),DATESBETWEEN(UTILISATION[Date],Fdate,Ldate)))/3

 

Rank = RANKX(ALLSELECTED(UTILISATION[Employee]),[Average],,DESC,Dense)


4. Create a table visual as follows, drag checkmonth  to visual level filters and set its value to 1. The second table visual doesn't require to set checkmonth.
3.JPG4.JPG

Community Support Team _ Lydia Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
AndyTrezise Helper II
Helper II

Re: Rank table over 3 different months

Thank you very much for the reply and detailed explanation.

 

Most of it makes sense 🙂

 

I'm a little unsure what the 'RankColumn' measure means (i.e. I don't understand the logic - particularly the part highlighted) or how it is being used in the solution.

 

RankColumn = RANKX(FILTER(UTILISATION,UTILISATION[Year]=EARLIER(UTILISATION[Year])&&UTILISATION[Month]=EARLIER(UTILISATION[Month])),UTILISATION[Utilisation],,DESC,Dense).

 

Thanks

Moderator v-yuezhe-msft
Moderator

Re: Rank table over 3 different months

@AndyTrezise,

This is a calculated column but not a measure, it calculates rank of utilisation of same year and same Month, which achieves your requirement.

Regards,
Lydia

Community Support Team _ Lydia Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

AndyTrezise Helper II
Helper II

Re: Rank table over 3 different months

Got it!

 

Thank you very much.

Helpful resources

Announcements
New Ranks Launched March 24th!

New Ranks Launched March 24th!

The time has come: We are finally able to share more details on the brand-new ranks coming to the Power BI Community!

‘Better Together’ Contest Finalists Announced!

‘Better Together’ Contest Finalists Announced!

Congrats to the finalists of our ‘Better Together’-themed T-shirt design contest! Click for the top entries.

Arun 'Triple A' Event Video, Q&A, and Slides

Arun 'Triple A' Event Video, Q&A, and Slides

Missed the Arun 'Triple A' event or want to revisit it? We've got you covered! Check out the video, Q&A, and slides now.

Join THE global Microsoft Power Platform event series.

Join THE global Power Platform event series.

Attend for two days of expert-led learning and innovation on topics like AI and Analytics, powered by Dynamic Communities.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Top Solution Authors