cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mohittimpus
Helper V
Helper V

How to get Median value Replicate in all selected months with respect to Fiscal Month

I have 2 Tables:

1) Date

2) Employee_Info


'Date' master table is connected with Employee_Info.


I have created one table visualization inside Employe_Info.pbix file. Table is filter with Year.


1) Inside Employee_Info.pbix "Fiscal Month" is taking from Date table, after that I created one Measure with name "#Count Employee" which calculate total 'Count of Employee' column.

 

#Count Employee = CALCULATE(SUM(Employee_Info[Count of Employee]))

 

2) After that I created  Measure with name "Rank of Employee" Which is getting rank of Employee based on fiscal Month.

 

Rank of Employee = if([#Count Employee]>0 || [#Count Employee]<>BLANK(),RANKX (FILTER(ALLSELECTED('Date'[Fiscal Month]),[#Count Employee]<>0 || [#Count Employee]<>BLANK()), [#Count Employee],,ASC,Dense))

3) finally I am calculating 'Median' of "#Count Employee" for that I have created Measure with name "Median_of_Emp" with couple of steps followed inside "Median_of_Emp" Measure. 


Median_of_Emp =
VAR Step1for_Emp_Median = [#Count Employee]
VAR Step2for_Emp_Median = IF([#Count Employee]>0,CALCULATE(CALCULATE(DISTINCTCOUNTNOBLANK('Date'[Fiscal MonthNumber]), FILTER(Employee_Info,[#Count Employee]>0)),ALL('Date'[Fiscal Month])))
VAR Step3for_Emp_Median = IF([#Count Employee]>0,CALCULATE( IF(MOD(Step2for_Emp_Median,2)=0, Step2for_Emp_Median/2, (Step2for_Emp_Median+1)/2) ,all('Date'[Fiscal Month])))
VAR Median_of_Emp = IF([Rank of Employee]=Step3for_Emp_Median,[#Count Employee])
Return Median_of_Emp

 

******Now I am not getting value 40 for  "Median_of_Employee" Measure for 3 Fiscal month Jan-Feb-Mar. But I am getting value for 12 Fiscal Month. I need help for 3 Fiscal Month Jan-Feb-Mar Median_of_Employee.

Below I am showing image:

 

Screenshot_4.png

 

I am sharing .Pbix file link also:

https://www.dropbox.com/s/oqust5wuauw0k44/Employee_Info1.pbix?dl=0

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

Hi @mohittimpus 

Create measures

rank monthno =
IF (
    [#Count Employee] > 0
        || [#Count Employee] <> BLANK (),
    RANKX (
        FILTER (
            ALL ( 'Date'[Fiscal Month] ),
            [#Count Employee] <> 0
                || [#Count Employee] <> BLANK ()
        ),
        CALCULATE ( MAX ( 'Date'[Fiscal MonthNumber] ) ),
        ,
        ASC,
        DENSE
    )
)

rank modified = IF([#Count Employee]>0 || [#Count Employee]<>BLANK(), 
RANKX (
    FILTER(ALL ( 'Date'[Fiscal Month] ),[#Count Employee]>0 || [#Count Employee]<>BLANK()),
    [Rank of Employee]
        + DIVIDE (
            [rank monthno],
            ( COUNTROWS ( ALL ( 'Date'[Fiscal Month] ) ) + 1 )
        ),,ASC,Dense
))

count of months =
CALCULATE (
    DISTINCTCOUNT ( 'Date'[Fiscal Month] ),
    FILTER (
        ALL ( 'Date'[Fiscal Month] ),
        [#Count Employee] <> BLANK ()
            || [#Count Employee] > 0
    )
)

middle =
IF (
    MOD ( [count of months], 2 ) <> 0,
    ROUNDUP ( [count of months] / 2, 0 ),
    [count of months] / 2 & "," & [count of months] / 2 + 1
)

flag = SEARCH([rank modified],[middle],1,0)

Capture10.JPGCapture11.JPG

Best Regards
Maggie
Community Support Team _ Maggie Li
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-juanli-msft
Community Support
Community Support

Hi @mohittimpus 

Create measures

rank monthno =
IF (
    [#Count Employee] > 0
        || [#Count Employee] <> BLANK (),
    RANKX (
        FILTER (
            ALL ( 'Date'[Fiscal Month] ),
            [#Count Employee] <> 0
                || [#Count Employee] <> BLANK ()
        ),
        CALCULATE ( MAX ( 'Date'[Fiscal MonthNumber] ) ),
        ,
        ASC,
        DENSE
    )
)

rank modified = IF([#Count Employee]>0 || [#Count Employee]<>BLANK(), 
RANKX (
    FILTER(ALL ( 'Date'[Fiscal Month] ),[#Count Employee]>0 || [#Count Employee]<>BLANK()),
    [Rank of Employee]
        + DIVIDE (
            [rank monthno],
            ( COUNTROWS ( ALL ( 'Date'[Fiscal Month] ) ) + 1 )
        ),,ASC,Dense
))

count of months =
CALCULATE (
    DISTINCTCOUNT ( 'Date'[Fiscal Month] ),
    FILTER (
        ALL ( 'Date'[Fiscal Month] ),
        [#Count Employee] <> BLANK ()
            || [#Count Employee] > 0
    )
)

middle =
IF (
    MOD ( [count of months], 2 ) <> 0,
    ROUNDUP ( [count of months] / 2, 0 ),
    [count of months] / 2 & "," & [count of months] / 2 + 1
)

flag = SEARCH([rank modified],[middle],1,0)

Capture10.JPGCapture11.JPG

Best Regards
Maggie
Community Support Team _ Maggie Li
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

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

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

Top Solution Authors
Top Kudoed Authors