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

Counting highest number of employees on the same date (distinct count problem)

Hi!

 

Looking for help creating a measure to calculate the highest number of employees at the same time.

My data consists of a table of with employees and information connected to the employee. There is a line for each date for each employee. This is in order to track different employment data regarding employees over time.

I need to calculate the highest number of employees employed at any given date in a time period (year, quarter, month etc.) – at the same time!

I’m trying to use a simple distinct count function on the employee ID, but that counts the total unique employee ID’s in my table and doesn’t take into consideration that employee ID has to be present on the same date.

Also tried using the formula below but it doesn’t work either.

CALCULATE ( DISTINCTCOUNTNOBLANK ('Table'[EMP_KEY]) , GROUPBY (DATES , DATES[DATE] ) )

 

Example of data:

 

Date             EMP_KEY     Distinct count per date (not in table)

01-01-2021  1          

01-01-2021  2          

01-01-2021  3                 3 (01-01-2021)

02-01-2021  3          

02-01-2021  4

02-01-2021  5

02-01-2021  6

02-01-2021  7

02-01-2021  8                 6 (02-01-2021)

03-01-2021  9

03-01-2021  10               2 (03-01-2021)

 

The result I’m looking for in above example is 6 employees (since the highest distinct count is 6 on 02-01-2021), but in my report the result I get is 10 (since there are 10 distinct EMP_KEY’s in the table).

 

Any help is appreciated.

 

 

1 ACCEPTED SOLUTION

Hi

This could be solved in a few ways but I think the simplest is to use the MAXX function, this will loop over all dates in your selection and calculate the unique number of employees per date then return the highest value.

 

Max Number of employees =
MAXX (
    VALUES ( 'Emp'[Date] ),
    CALCULATE (
        DISTINCTCOUNT ( 'Emp'[EMP_KEY] )
    )
)

View solution in original post

2 REPLIES 2

Hi

This could be solved in a few ways but I think the simplest is to use the MAXX function, this will loop over all dates in your selection and calculate the unique number of employees per date then return the highest value.

 

Max Number of employees =
MAXX (
    VALUES ( 'Emp'[Date] ),
    CALCULATE (
        DISTINCTCOUNT ( 'Emp'[EMP_KEY] )
    )
)

View solution in original post

THANK YOU! Have been searching all day for a solution.

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

Get Ready for Power BI Dev Camp

Microsoft named a Leader in The Forrester Wave

Microsoft received the highest score of any vendor in both the strategy and current offering categories.

Get Ready for Power BI Dev Camp

Power BI Dev Camp - September 30th, 2021

Mark your calendars and join us for our next Power BI Dev Camp!

PowerPlatform 768x460.png

Microsoft Learn

Check out our new Discover Your Career Path blog post series and get all the details.

Top Solution Authors