Excel, PowerPivot
Using RankX in DAX for PowerPivot and PowerBI
February 4, 2017 - Excel, PowerPivot
A common reporting need is to rank a certain Attribute by a value. In DAX, the syntax is the following:
RANKX(<table>, <expression>[, <value>[, <order>[, <ties>]]])
Parameters
table
Any DAX expression that returns a table of data over which the expression is evaluated.
expression
Any DAX expression that returns a single scalar value. The expression is evaluated for each row of table, to generate all possible values for ranking. See the remarks section to understand the function behavior when expression evaluates to BLANK.
value
(Optional) Any DAX expression that returns a single scalar value whose rank is to be found. See the remarks section to understand the function’s behavior when value is not found in the expression.
When the value parameter is omitted, the value of expression at the current row is used instead.
order
(Optional) A value that specifies how to rank value, low to high or high to low
Let’s walk through an example, where I have the following data model and want to Rank each Manufacturer by their total sales.
When you start writing RANKX Measures, there are a couple common complications to be aware of. The most common attempt people will make the first time they write a RANKX Measure looks something like this:
Wrong Rank by Manufacturer := IF ( HASONEVALUE ( DimProduct[Manufacturer] ), RANKX ( DimProduct, [Total Sales] ) )
However, when we put this on a pivot table we see it doesn’t work as expected.
The issue here is the first value in the RankX function doesn’ t have an ALL(), which means each manufacturer is being ranked against itself(hence the 1 value in each row).
The second RANKX mistake I see a lot is this:
Wrong Rank(Without Calculate): =
IF(
HASONEVALUE(DimProduct[Manufacturer]),
RANKX(ALL(DimProduct), SUM([TotalCost]))
This expression returns the same results we saw with the first calculation.The DAX formula is aggregating rows without a Calculate wrapping it up, so the row context is not transformed into a filter context.
Finally, we get to the correct methods for using RANKX.
Rank by Manufacturer: =
RANKX(ALL(DimProduct[Manufacturer]), [Total Sales])
Rank by Manufacturer(Excluding Grand Totals): =
IF(
HASONEVALUE(DimProduct[Manufacturer]),
RANKX(ALL(DimProduct[Manufacturer]), [Total Sales])
Rank by Visible Manufacturers: =
IF(
HASONEVALUE(DimProduct[Manufacturer]),
RANKX(ALLSELECTED(DimProduct[Manufacturer]), [Total Sales])
Putting these DAX Measures on a pivot table we see the correct results: