cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
key_to
Frequent Visitor

Distinct count of active employees over time period

Hello.
 
I am strugglig to get my number of employees by month right. The issue is that some employees hold two positions and appear each month twice. I don't know how to include "if a variable is true, count distinct"  into my formula below.  The 'Var result' with the 'if' formula does not work. 
 
Distinct count of active employees =
VAR currentDate =
    MAX ( 'DimDates'[Dates] )
VAR _active =
        FILTER (
            FactEmployement,
            ('FactEmployement'[Ansatt fra] <= currentDate
                && OR((FactEmployement[Ansatt til] >= currentDate ), ISBLANK(FactEmployement[Ansatt til]))
        )
    )
    VAR result = CALCULATE(DISTINCTCOUNT(FactEmployement[Ansattnr]),IF(_active=1,1,0))
    Return result
 
I would appreciate any suggestion!
Thanks in advance!
1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

I am not sure how your datamodel looks like, but please try disconnect the relationship between date table and fact table. And then try the below measure.

 

Distinct count of active employees =
VAR _active =
    SUMMARIZE (
        FILTER (
            FactEmployement,
            (
                'FactEmployement'[Ansatt fra] <= MAX ( 'DimDates'[Dates] )
                    && OR (
                        ( FactEmployement[Ansatt til] >= MIN ( 'DimDates'[Dates] ) ),
                        ISBLANK ( FactEmployement[Ansatt til] )
                    )
            )
        ),
        FactEmployement[Ansattnr]
    )
VAR result =
    COUNTROWS ( _active )
RETURN
    result

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

3 REPLIES 3
Ashish_Mathur
Super User
Super User

Hi,

Share some data and show the expected result.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Jihwan_Kim
Super User
Super User

Hi,

I am not sure how your datamodel looks like, but please try disconnect the relationship between date table and fact table. And then try the below measure.

 

Distinct count of active employees =
VAR _active =
    SUMMARIZE (
        FILTER (
            FactEmployement,
            (
                'FactEmployement'[Ansatt fra] <= MAX ( 'DimDates'[Dates] )
                    && OR (
                        ( FactEmployement[Ansatt til] >= MIN ( 'DimDates'[Dates] ) ),
                        ISBLANK ( FactEmployement[Ansatt til] )
                    )
            )
        ),
        FactEmployement[Ansattnr]
    )
VAR result =
    COUNTROWS ( _active )
RETURN
    result

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thank you so much! This is exactly what I was looking for! 

Helpful resources

Announcements
collabdays lisbon

CollabDays Lisbon - 26 November 2022

Sessions include practical, hands-on experience that will help you take the next step in your career and know-how.

Difinity Conference

Difinity Conference 2022

Difinity is the largest Microsoft Data, AI, Power BI, Power Platform and Business Applications Conference in New Zealand.

European Share Point Conference

European Share Point Conference

This conference returns live and in-person in Copenhagen this 28 November-01 December with 4 Microsoft Keynotes, 9 Tutorials, and 120 Sessions.

Microsoft 365 Conference â__ December 6-8, 2022

Microsoft 365 Conference - 06-08 December

Join us in Las Vegas to experience community, incredible learning opportunities, and connections that will help grow skills, know-how, and more.