Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
dupreem
Frequent Visitor

Headcount Over Time From Transactional Data

Hello,

 

I am working on building Turnover functionality and need to know headcount at a certain point in time.  The transactional data I am using looks something like this:

 

Employee ID 

Event Date 

Status

1

1/1/20

Active 

2

1/1/20

Active 

3

2/1/20 

Active 

1

3/1/20

Terminated 

2

3/1/20

Active 

3

3/1/20

Active 

1

4/1/20

Active

 

Based on the transactional data above I would expect to see end of the month headcount for each month to be: Jan = 2, Feb = 3, Mar = 2, Apr = 3.

 

Employees will have multiple transactions for their Employee ID.

 

Any help is greatly appreciated!

 

1 ACCEPTED SOLUTION

@dupreem -

Measure 14 = 
    VAR __Date = MAX([Event Date ])
    VAR __Active = DISTINCT(SELECTCOLUMNS(FILTER(ALL('Table (14)'),[Event Date ]<=__Date && [Status]="Active"),"ID",[Employee ID ]))
    VAR __Term = DISTINCT(SELECTCOLUMNS(FILTER(ALL('Table (14)'),[Event Date ]<=__Date && ([Status]="Terminated" || [Status]="Retiree" || [Status]="Dead")),"ID",[Employee ID ]))
RETURN
    COUNTROWS(EXCEPT(__Active, __Term))

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

4 REPLIES 4
Greg_Deckler
Super User
Super User

@dupreem - See attached PBIX file below sig, Page 14

Measure 14 = 
    VAR __Date = MAX([Event Date ])
    VAR __Active = DISTINCT(SELECTCOLUMNS(FILTER(ALL('Table (14)'),[Event Date ]<=__Date && [Status]="Active"),"ID",[Employee ID ]))
    VAR __Term = DISTINCT(SELECTCOLUMNS(FILTER(ALL('Table (14)'),[Event Date ]<=__Date && [Status]="Terminated"),"ID",[Employee ID ]))
RETURN
    COUNTROWS(EXCEPT(__Active, __Term))

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler  Thank you so much!  If I have multiple "Terminated" statuses (i.e. "Terminated, Retiree), how would I update the Measure?

@dupreem -

Measure 14 = 
    VAR __Date = MAX([Event Date ])
    VAR __Active = DISTINCT(SELECTCOLUMNS(FILTER(ALL('Table (14)'),[Event Date ]<=__Date && [Status]="Active"),"ID",[Employee ID ]))
    VAR __Term = DISTINCT(SELECTCOLUMNS(FILTER(ALL('Table (14)'),[Event Date ]<=__Date && ([Status]="Terminated" || [Status]="Retiree" || [Status]="Dead")),"ID",[Employee ID ]))
RETURN
    COUNTROWS(EXCEPT(__Active, __Term))

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler  You rock!  Thank you so much!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.