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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
ranjitsingh
Advocate I
Advocate I

Challenge ?

Hi All,

 

I have the following sales table where I need to find annual ranking of salesperson.

 

There is a small complication....

 

The ranking depends not only on number of annual car sales by the sales person but also takes into account how long the employee has been with the company. Shorter employment period is ranked higher. E.g. Sale of 70 cars for sonita will be ranked higher than sale of 70 cars by ravita as sonita has been with the company since only 2019, and still sold the same # of cars as ravita who has much greater experience..

 

Not sure how to write this in DAX to get a ranking system...?? 

 

EMPLOYEE_IDFIRST_NAMEAnnual Car SalesDate of JoiningAnnual Ranking
100vinita1101-Jan-05 
110sonita7012-Jun-19 
120ravita7019-Apr-04 
130sarita501-Mar-08 
140minita9512-Feb-20 
150binita302-Oct-14 
160lonita4516-Sep-11 
170robita6511-Oct-09 
180papita274-May-18 
190tomita2023-Dec-20 

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

DEFINE
MEASURE 'Ranking Exercise'[Total Sales] =
    SUM( 'Ranking Exercise'[Annual Car Sales] )
    
MEASURE 'Ranking Exercise'[Tenure Days] =
    // You need to create a column 'Ranking Exercise'[Days With Company]
    // that will equal Today() - RankingExercise[Date of Joining].
    // or you can replace the SUM below with:
    //    SUMX(
    //        'Ranking Exercise',
    //        TODAY() - 'Ranking Exercise'[Date of Joining]
    //    )
    SUM( 'Ranking Exercise'[Days With Company] )

MEASURE 'Ranking Exercise'[Employee Rank] =
IF( ISINSCOPE( 'Ranking Exercise'[FIRST_NAME] ),
    var vEmps =
        ALLSELECTED(
            'Ranking Exercise'[FIRST_NAME] 
        )
    var vEmpsWithRanks =
        ADDCOLUMNS(
            vEmps,
            "@EmpRank",
                CALCULATE(
                    RANKX(
                        vEmps,
                        [Total Sales],,
                        DESC
                    )                
                )
        )
    var vCurrentEmp = SELECTEDVALUE( 'Ranking Exercise'[FIRST_NAME] )
    var vCurrentEmpRank =
        MAXX(
            FILTER(
                vEmpsWithRanks,
                'Ranking Exercise'[FIRST_NAME] = vCurrentEmp
            ),
            [@EmpRank]
        )
    var vEmpsWithSameRank =
        FILTER(
            vEmpsWithRanks,
            [@EmpRank] = vCurrentEmpRank
        )
    var vThereAreOthersWithSameRank =
        COUNTROWS( vEmpsWithSameRank ) > 1
    var vResult =
        if( not vThereAreOthersWithSameRank,
            vCurrentEmpRank,
            
            // Rank these others with the current one
            // based on days with company where a
            // lower rank means shorter period with
            // the company.
            
            vCurrentEmpRank - 1 +
            RANKX(
                vEmpsWithSameRank,
                [Tenure Days],,
                ASC
            )
            
        )
    RETURN
        vResult
)
        
EVALUATE
    SUMMARIZECOLUMNS(
        'Ranking Exercise'[FIRST_NAME],
        "Total Sales", [Total Sales],
        "Tenure Days", [Tenure Days],
        "Employee Rank", [Employee Rank]
    )
ORDER BY
    [Employee Rank],
    [Total Sales] desc,
    [Tenure Days] desc

The code above is a DAX query that demonstrates how to construct a ranking measure that satisfies your requirements. Out of this, it's easy to just write the measure in PBI. Actually, it's already been written. It's 'Ranking Exercise'[Employee Rank]. You just have to adjust the names of some objects.

View solution in original post

1 REPLY 1
Anonymous
Not applicable

DEFINE
MEASURE 'Ranking Exercise'[Total Sales] =
    SUM( 'Ranking Exercise'[Annual Car Sales] )
    
MEASURE 'Ranking Exercise'[Tenure Days] =
    // You need to create a column 'Ranking Exercise'[Days With Company]
    // that will equal Today() - RankingExercise[Date of Joining].
    // or you can replace the SUM below with:
    //    SUMX(
    //        'Ranking Exercise',
    //        TODAY() - 'Ranking Exercise'[Date of Joining]
    //    )
    SUM( 'Ranking Exercise'[Days With Company] )

MEASURE 'Ranking Exercise'[Employee Rank] =
IF( ISINSCOPE( 'Ranking Exercise'[FIRST_NAME] ),
    var vEmps =
        ALLSELECTED(
            'Ranking Exercise'[FIRST_NAME] 
        )
    var vEmpsWithRanks =
        ADDCOLUMNS(
            vEmps,
            "@EmpRank",
                CALCULATE(
                    RANKX(
                        vEmps,
                        [Total Sales],,
                        DESC
                    )                
                )
        )
    var vCurrentEmp = SELECTEDVALUE( 'Ranking Exercise'[FIRST_NAME] )
    var vCurrentEmpRank =
        MAXX(
            FILTER(
                vEmpsWithRanks,
                'Ranking Exercise'[FIRST_NAME] = vCurrentEmp
            ),
            [@EmpRank]
        )
    var vEmpsWithSameRank =
        FILTER(
            vEmpsWithRanks,
            [@EmpRank] = vCurrentEmpRank
        )
    var vThereAreOthersWithSameRank =
        COUNTROWS( vEmpsWithSameRank ) > 1
    var vResult =
        if( not vThereAreOthersWithSameRank,
            vCurrentEmpRank,
            
            // Rank these others with the current one
            // based on days with company where a
            // lower rank means shorter period with
            // the company.
            
            vCurrentEmpRank - 1 +
            RANKX(
                vEmpsWithSameRank,
                [Tenure Days],,
                ASC
            )
            
        )
    RETURN
        vResult
)
        
EVALUATE
    SUMMARIZECOLUMNS(
        'Ranking Exercise'[FIRST_NAME],
        "Total Sales", [Total Sales],
        "Tenure Days", [Tenure Days],
        "Employee Rank", [Employee Rank]
    )
ORDER BY
    [Employee Rank],
    [Total Sales] desc,
    [Tenure Days] desc

The code above is a DAX query that demonstrates how to construct a ranking measure that satisfies your requirements. Out of this, it's easy to just write the measure in PBI. Actually, it's already been written. It's 'Ranking Exercise'[Employee Rank]. You just have to adjust the names of some objects.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors