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

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.

Reply
Anonymous
Not applicable

Conditional Drilldown or Previous Level Distinct Count

Dear Team,

I am trying to build a Span of Control logic and count the number of management that reports to the previous level of management.

I have the next data set with 5 levels of management.

Level 1Level 2Level 3Level 4Level 5
astoy@test.comrmahom@test.comyfedor@test.comssia@test.comjbanan@test.com
tpesh@test.comrmahom@test.comyfedor@test.comssia@test.comjbanan@test.com
alivanov@test.comrmahom@test.comyfedor@test.comssia@test.comjbanan@test.com
vtuto@test.comrmahom@test.comcapst@test.comssia@test.comjbanan@test.com
mnikolai@test.comrmahom@test.comcapst@test.comssia@test.comjbanan@test.com
mvasylch@test.comrmahom@test.comdorer@test.comfredod@test.comjbanan@test.com
olen@test.comosili@test.comdorer@test.comfredod@test.comjbanan@test.com
vverbi@test.comosili@test.comdorer@test.comfredod@test.comjbanan@test.com
sprok@test.comosili@test.comdorer@test.comfredod@test.comjbanan@test.com
kwiat@test.comrvolo@test.comgrabs@test.comfredod@test.comjbanan@test.com
vbatluk@test.comrmahom@test.comgrabs@test.comfredod@test.comjbanan@test.com
dpota@test.comosili@test.comgrabs@test.comfredod@test.comjbanan@test.com

 

I must have a matrix that would count the distinct amount of managers that report to the previous level. I would like to receive the expected count like in the picture:

mvakhi_0-1668123627772.png

Could you please share any ideas on how it must be calculated?

Very much appreciate your help.

Thank you and have a great day.

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi  @Anonymous ,

Here are the steps you can follow:

1. Create measure.

 

Level3 =
CALCULATE(DISTINCTCOUNT('Table'[Level 2]),FILTER(ALL('Table'),'Table'[Level 3]=MAX('Table'[Level 3])))
Flag =
IF (
    ISINSCOPE ( 'Table'[Level 5] )
        && NOT ( ISINSCOPE ( 'Table'[Level 1] ) )
            && NOT ( ISINSCOPE ( 'Table'[Level 2] ) )
                && NOT ( ISINSCOPE ( 'Table'[Level 3] ) ) && NOT ( ISINSCOPE ( 'Table'[Level 4] ) ),
    2,
    IF (
        ISINSCOPE ( 'Table'[Level 4] )
            && NOT ( ISINSCOPE ( 'Table'[Level 1] ) )
                && NOT ( ISINSCOPE ( 'Table'[Level 2] ) ) && NOT ( ISINSCOPE ( 'Table'[Level 3] ) ),
        CALCULATE (
            DISTINCTCOUNT ( 'Table'[Level 4] ),
            FILTER ( ALL ( 'Table' ), 'Table'[Level 5] = MAX ( 'Table'[Level 5] ) )
        ),
        IF (
            ISINSCOPE ( 'Table'[Level 3] )
                && NOT ( ISINSCOPE ( 'Table'[Level 1] ) ) && NOT ( ISINSCOPE ( 'Table'[Level 2] ) ),
            CALCULATE (
                DISTINCTCOUNT ( 'Table'[Level 3] ),
                FILTER ( ALL ( 'Table' ), 'Table'[Level 4] = MAX ( 'Table'[Level 4] ) )
            ),
            IF (
                ISINSCOPE ( 'Table'[Level 2] ) && NOT ( ISINSCOPE ( 'Table'[Level 1] ) ),
                MAXX ( ALL ( 'Table' ), [Level3] ),
                IF (
                    ISINSCOPE ( 'Table'[Level 1] ),
                    CALCULATE (
                        DISTINCTCOUNT ( 'Table'[Level 1] ),
                        FILTER ( ALL ( 'Table' ), 'Table'[Level 1] = MAX ( 'Table'[Level 1] ) )
                    ),
                    CALCULATE ( DISTINCTCOUNT ( 'Table'[Level 1] ) )
                )
            )
        )
    )
)

 

2. Result:

vyangliumsft_0-1668149680863.png

 

Best Regards,

Liu Yang

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
Anonymous
Not applicable

Hi  @Anonymous ,

Here are the steps you can follow:

1. Create measure.

 

Level3 =
CALCULATE(DISTINCTCOUNT('Table'[Level 2]),FILTER(ALL('Table'),'Table'[Level 3]=MAX('Table'[Level 3])))
Flag =
IF (
    ISINSCOPE ( 'Table'[Level 5] )
        && NOT ( ISINSCOPE ( 'Table'[Level 1] ) )
            && NOT ( ISINSCOPE ( 'Table'[Level 2] ) )
                && NOT ( ISINSCOPE ( 'Table'[Level 3] ) ) && NOT ( ISINSCOPE ( 'Table'[Level 4] ) ),
    2,
    IF (
        ISINSCOPE ( 'Table'[Level 4] )
            && NOT ( ISINSCOPE ( 'Table'[Level 1] ) )
                && NOT ( ISINSCOPE ( 'Table'[Level 2] ) ) && NOT ( ISINSCOPE ( 'Table'[Level 3] ) ),
        CALCULATE (
            DISTINCTCOUNT ( 'Table'[Level 4] ),
            FILTER ( ALL ( 'Table' ), 'Table'[Level 5] = MAX ( 'Table'[Level 5] ) )
        ),
        IF (
            ISINSCOPE ( 'Table'[Level 3] )
                && NOT ( ISINSCOPE ( 'Table'[Level 1] ) ) && NOT ( ISINSCOPE ( 'Table'[Level 2] ) ),
            CALCULATE (
                DISTINCTCOUNT ( 'Table'[Level 3] ),
                FILTER ( ALL ( 'Table' ), 'Table'[Level 4] = MAX ( 'Table'[Level 4] ) )
            ),
            IF (
                ISINSCOPE ( 'Table'[Level 2] ) && NOT ( ISINSCOPE ( 'Table'[Level 1] ) ),
                MAXX ( ALL ( 'Table' ), [Level3] ),
                IF (
                    ISINSCOPE ( 'Table'[Level 1] ),
                    CALCULATE (
                        DISTINCTCOUNT ( 'Table'[Level 1] ),
                        FILTER ( ALL ( 'Table' ), 'Table'[Level 1] = MAX ( 'Table'[Level 1] ) )
                    ),
                    CALCULATE ( DISTINCTCOUNT ( 'Table'[Level 1] ) )
                )
            )
        )
    )
)

 

2. Result:

vyangliumsft_0-1668149680863.png

 

Best Regards,

Liu Yang

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

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors