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

employee master and transfer data

Hi

I have to crack i more logic i have two table like below

1. Live employee Master table

empcodeBUfunction
E100AGRIHR
E101ECER&D
E102AGRIFin
E103AGRIHR

 

2. Transfer table

empcodeAttributeTypeDescriptionNewAttributeDescOLDAttributeDescEffectiveDate
E100BUAGRIECE01-Apr-22
E101FunctionR&DFin5-May-22

 

i have already created calender table

need to create data like if slicer ( BU is AGRI and Fun is HR) 

Monthheadcount
feb-221
mar-221
apr-222
may-222
june-222
and so on2

 

if slicer  (BU is ECE and Fun is R&D)

Monthheadcount
feb-220
mar-220
apr-220
may-221
june-221
and so on1

 

pls help

1 ACCEPTED SOLUTION
v-jialluo-msft
Community Support
Community Support

Hi @Lalit_101 ,

 

Please follow these steps:

(1) Create a new Table

Table = 
SELECTCOLUMNS (
    'Transfer',
    "empcode", [empcode],
    "EffectiveDate", [EffectiveDate],
    "BU",
        IF (
            CALCULATE (
                DISTINCTCOUNT ( 'Transfer'[AttributeTypeDescription] ),
                FILTER (
                    ALLEXCEPT ( 'Transfer', 'Transfer'[empcode] ),
                    [AttributeTypeDescription] = "BU"
                )
            ) > 0,
            IF ( [AttributeTypeDescription] = "BU", [OLDAttributeDesc] ),
            CALCULATE (
                MAX ( 'Live employee'[BU] ),
                FILTER ( 'Live employee', [empcode] = EARLIER ( 'Transfer'[empcode] ) )
            )
        ),
    "Funtion",
        IF (
            CALCULATE (
                DISTINCTCOUNT ( 'Transfer'[AttributeTypeDescription] ),
                FILTER (
                    ALLEXCEPT ( 'Transfer', 'Transfer'[empcode] ),
                    [AttributeTypeDescription] = "Function"
                )
            ) > 0,
            IF ( [AttributeTypeDescription] = "Function", [OLDAttributeDesc] ),
            CALCULATE (
                MAX ( 'Live employee'[function] ),
                FILTER ( 'Live employee', [empcode] = EARLIER ( 'Transfer'[empcode] ) )
            )
        )
)

(2) Create a new measure

headcount = 
CALCULATE (
    COUNT ( 'Live employee'[empcode] ),
    FILTER (
        'Live employee',
        RELATED ( 'Transfer'[EffectiveDate] ) = BLANK ()
            || EOMONTH ( RELATED ( Transfer[EffectiveDate] ), 0 )
                <= EOMONTH ( MIN ( 'calender'[Date] ), 0 )
    )
)
    + CALCULATE (
        COUNT ( 'Table'[empcode] ),
        FILTER (
            'Table',
            EOMONTH ( [EffectiveDate], 0 ) > EOMONTH ( MAX ( 'calender'[Date] ), 0 )
                && [Funtion]
                    IN VALUES ( 'Live employee'[function] )
                        && [BU] IN VALUES ( 'Live employee'[BU] )
        )
    )

(3)Final output

vjialluomsft_0-1669793199322.png

 

vjialluomsft_1-1669793199323.png

 

 

Best Regards,

Gallen Luo

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

1 REPLY 1
v-jialluo-msft
Community Support
Community Support

Hi @Lalit_101 ,

 

Please follow these steps:

(1) Create a new Table

Table = 
SELECTCOLUMNS (
    'Transfer',
    "empcode", [empcode],
    "EffectiveDate", [EffectiveDate],
    "BU",
        IF (
            CALCULATE (
                DISTINCTCOUNT ( 'Transfer'[AttributeTypeDescription] ),
                FILTER (
                    ALLEXCEPT ( 'Transfer', 'Transfer'[empcode] ),
                    [AttributeTypeDescription] = "BU"
                )
            ) > 0,
            IF ( [AttributeTypeDescription] = "BU", [OLDAttributeDesc] ),
            CALCULATE (
                MAX ( 'Live employee'[BU] ),
                FILTER ( 'Live employee', [empcode] = EARLIER ( 'Transfer'[empcode] ) )
            )
        ),
    "Funtion",
        IF (
            CALCULATE (
                DISTINCTCOUNT ( 'Transfer'[AttributeTypeDescription] ),
                FILTER (
                    ALLEXCEPT ( 'Transfer', 'Transfer'[empcode] ),
                    [AttributeTypeDescription] = "Function"
                )
            ) > 0,
            IF ( [AttributeTypeDescription] = "Function", [OLDAttributeDesc] ),
            CALCULATE (
                MAX ( 'Live employee'[function] ),
                FILTER ( 'Live employee', [empcode] = EARLIER ( 'Transfer'[empcode] ) )
            )
        )
)

(2) Create a new measure

headcount = 
CALCULATE (
    COUNT ( 'Live employee'[empcode] ),
    FILTER (
        'Live employee',
        RELATED ( 'Transfer'[EffectiveDate] ) = BLANK ()
            || EOMONTH ( RELATED ( Transfer[EffectiveDate] ), 0 )
                <= EOMONTH ( MIN ( 'calender'[Date] ), 0 )
    )
)
    + CALCULATE (
        COUNT ( 'Table'[empcode] ),
        FILTER (
            'Table',
            EOMONTH ( [EffectiveDate], 0 ) > EOMONTH ( MAX ( 'calender'[Date] ), 0 )
                && [Funtion]
                    IN VALUES ( 'Live employee'[function] )
                        && [BU] IN VALUES ( 'Live employee'[BU] )
        )
    )

(3)Final output

vjialluomsft_0-1669793199322.png

 

vjialluomsft_1-1669793199323.png

 

 

Best Regards,

Gallen Luo

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

BizApps LATAM 2023

Business Application LATAM Summit 2023

Join the biggest FREE Business Applications Event in LATAM this February.

Power Platform Bootcamp

Global Power Platform Bootcamp

In this bootcamp we will deep-dive into Microsoft’s Power Platform stack with hands-on sessions and labs, delivered to you by experts and community leaders.