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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
NilR
Post Patron
Post Patron

DAX Issue- Rankx by multiple Categories

I have 4 Categories (GP, ID, Age, Date). I would would like to create calculated column and group by GP, ID, and Age and Rank/ count by Date to see how many months each member has in past 24 month.

My Code works until I have members who cancelled their membership for a few months and then resumed after. I need to restart from the first month after skip. for example :

GROUPIDAGEDATECurrent RankDesired RANK
122035-44202206126
122035-44202205125
122035-44202204124
122035-44202203123
122035-44202202122
122035-44202201121
122035-442020122424
122035-442020112323
122035-442020102222
122035-442020092121
122035-442020082020
122035-442020071919
122035-442020061818
122035-442020051717
122035-442020041616
122035-4420190111

This is what I have tried but doesn't work for dates skipping.

RKING= 
RANKX (
CALCULATETABLE (
               VALUES ('tbl'[Date] ),
               ALLEXCEPT ( 'tblW', 'tbl'[GP], 'tbl'[ID] ),
                         'tbl'[AGE] = 'tbl'[AGE],
                         'tbl'[date] >= start_date && 'tbl'[date] <= end_date // date slicer
                ),
[Date] ,
,ASC
)

 

1 ACCEPTED SOLUTION
vapid128
Solution Specialist
Solution Specialist

OH OH sorry,

I didnt get what your mean.

 

image.png

 

rank =
RANKX(
    FILTER(
        'Table',
        [GROUP]=EARLIER('Table'[GROUP]) &&
        [ID]=EARLIER('Table'[ID]) &&
        [AGE]=EARLIER('Table'[AGE])
    ),
    [DATE],
    ,
    ASC
)
 
 
Month>1 =
var _NextMonth =
LOOKUPVALUE(
    'Table'[DATE],
    [GROUP],[GROUP],
    [ID],[ID],
    [AGE],[AGE],
    [rank],[rank] +1
)

return (_NextMonth-[DATE])>1
 
 
sessionID =
RANKX(
    FILTER(
        'Table',
        [GROUP]=EARLIER('Table'[GROUP]) &&
        [ID]=EARLIER('Table'[ID]) &&
        [AGE]=EARLIER('Table'[AGE]) &&
        [Month>1]
    ),
    [DATE],
    ,
    ASC
)
 
 
ID_in_Session =
RANKX(
    FILTER(
        'Table',
        [GROUP]=EARLIER('Table'[GROUP]) &&
        [ID]=EARLIER('Table'[ID]) &&
        [AGE]=EARLIER('Table'[AGE]) &&
        [sessionID]=EARLIER('Table'[sessionID])
    ),
    [DATE],
    ,
    ASC
)

View solution in original post

4 REPLIES 4
vapid128
Solution Specialist
Solution Specialist

RKING=
RANKX (

    Filter(

        'tblW',

        'tbl'[AGE] = EARLIER('tbl'[AGE]) &&

        'tbl'[ID] = EARLIER('tbl'[ID]) &&

        'tbl'[GROUP] = EARLIER('tbl'[GROUP])

    ),

    'tbl'[DATE],

    ,

    ASC

)

@vapid128 Thank you! still doesn't reset the date.

vapid128
Solution Specialist
Solution Specialist

OH OH sorry,

I didnt get what your mean.

 

image.png

 

rank =
RANKX(
    FILTER(
        'Table',
        [GROUP]=EARLIER('Table'[GROUP]) &&
        [ID]=EARLIER('Table'[ID]) &&
        [AGE]=EARLIER('Table'[AGE])
    ),
    [DATE],
    ,
    ASC
)
 
 
Month>1 =
var _NextMonth =
LOOKUPVALUE(
    'Table'[DATE],
    [GROUP],[GROUP],
    [ID],[ID],
    [AGE],[AGE],
    [rank],[rank] +1
)

return (_NextMonth-[DATE])>1
 
 
sessionID =
RANKX(
    FILTER(
        'Table',
        [GROUP]=EARLIER('Table'[GROUP]) &&
        [ID]=EARLIER('Table'[ID]) &&
        [AGE]=EARLIER('Table'[AGE]) &&
        [Month>1]
    ),
    [DATE],
    ,
    ASC
)
 
 
ID_in_Session =
RANKX(
    FILTER(
        'Table',
        [GROUP]=EARLIER('Table'[GROUP]) &&
        [ID]=EARLIER('Table'[ID]) &&
        [AGE]=EARLIER('Table'[AGE]) &&
        [sessionID]=EARLIER('Table'[sessionID])
    ),
    [DATE],
    ,
    ASC
)
Jihwan_Kim
Super User
Super User

Hi,

I am not sure how your data model looks like, but I tried to create a sample pbix file like below.

Please check the below picture and the attached file.

I hope this can provide some ideas on creating a solution to your problem.

 

Untitled.png

 

step one Previousmonthmembership: = 
VAR _currentdate =
    MAX ( Data[DATE] )
VAR _currentgroup =
    MAX ( Data[GROUP] )
VAR _currentid =
    MAX ( Data[ID] )
VAR _currentage =
    MAX ( Data[AGE] )
RETURN
    MAXX (
        FILTER (
            ALLSELECTED ( Data ),
            Data[GROUP] = _currentgroup
                && Data[ID] = _currentid
                && Data[AGE] = _currentage
                && Data[DATE] < _currentdate
        ),
        Data[DATE]
    )

 

step two currentgroupindex: = 
VAR _currentdate =
    MAX ( Data[DATE] )
VAR _currentgroup =
    MAX ( Data[GROUP] )
VAR _currentid =
    MAX ( Data[ID] )
VAR _currentage =
    MAX ( Data[AGE] )
VAR _addindexcolumn =
    ADDCOLUMNS (
        ADDCOLUMNS (
            ALLSELECTED ( Data ),
            "@memberpreviousmonth", [step one Previousmonthmembership:]
        ),
        "@consecutivecondition",
            SWITCH (
                TRUE (),
                [@memberpreviousmonth] = BLANK (), 0,
                Data[DATE] - [@memberpreviousmonth] > 31, 1,
                0
            )
    )
VAR _addgroupingcolumn =
    ADDCOLUMNS (
        _addindexcolumn,
        "@groupindex",
            SUMX (
                FILTER ( _addindexcolumn, Data[DATE] <= _currentdate ),
                [@consecutivecondition]
            )
    )
VAR _currentgroupindex =
    MAXX ( FILTER ( _addgroupingcolumn, Data[DATE] = _currentdate ), [@groupindex] )
RETURN
    _currentgroupindex

 

step three Ranking measure: = 
VAR _currentgroupindex = [step two currentgroupindex:]
RETURN
    IF (
        COUNTROWS ( Data ) <> BLANK (),
        RANKX (
            FILTER ( ALLSELECTED ( Data ), [step two currentgroupindex:] = _currentgroupindex ),
            CALCULATE ( MAX ( Data[DATE] ) ),
            ,
            ASC
        )
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors