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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
Sofinobi
Helper IV
Helper IV

top 6 month sales by client

hello,

i have a measure to calculate the total sales
[total Sales]
please, i want to calculate the top 6 sales by month by client ( start date from 06/2022 to 09/2023)

(the best 6 sales by month for each client)

thank you

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

Hi @Sofinobi ,

 

I suggest you to create a Calendar table which is connected to your data table to help your calculation.

Calendar = ADDCOLUMNS(CALENDARAUTO(),"YearMonth",YEAR([Date]) * 100 +MONTH([Date]),"Month/Year",COMBINEVALUES("/",FORMAT(MONTH([Date]),"00"),YEAR([Date])))

Then create a rank measure.

Rank = 
VAR _SUMMARIZE =
    SUMMARIZE (
        ADDCOLUMNS ( ALL ( 'Table' ), "Month/Year", RELATED ( 'Calendar'[Month/Year] ) ),
        [Month/Year],
        [Customer],
        "Sum",
            SUMX (
                ADDCOLUMNS ( 'Table', "Month/Year", RELATED ( 'Calendar'[Month/Year] ) ),
                [Sales]
            )
    )
VAR _ADDRANK =
    ADDCOLUMNS (
        _SUMMARIZE,
        "RANKX",
            RANKX (
                FILTER ( _SUMMARIZE, [Month/Year] = EARLIER ( [Month/Year] ) ),
                [Sum],
                ,
                DESC,
                DENSE
            )
    )
RETURN
    SUMX (
        FILTER (
            _ADDRANK,
            [Month/Year] = MAX ( 'Calendar'[Month/Year] )
                && [Customer] = MAX ( 'Table'[Customer] )
        ),
        [RANKX]
    )

Add this measure into visual level filter and set it to show items when value <=6.

vrzhoumsft_0-1696410527757.png

 

Best Regards,
Rico Zhou

 

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-rzhou-msft
Community Support
Community Support

Hi @Sofinobi ,

 

I suggest you to create a Calendar table which is connected to your data table to help your calculation.

Calendar = ADDCOLUMNS(CALENDARAUTO(),"YearMonth",YEAR([Date]) * 100 +MONTH([Date]),"Month/Year",COMBINEVALUES("/",FORMAT(MONTH([Date]),"00"),YEAR([Date])))

Then create a rank measure.

Rank = 
VAR _SUMMARIZE =
    SUMMARIZE (
        ADDCOLUMNS ( ALL ( 'Table' ), "Month/Year", RELATED ( 'Calendar'[Month/Year] ) ),
        [Month/Year],
        [Customer],
        "Sum",
            SUMX (
                ADDCOLUMNS ( 'Table', "Month/Year", RELATED ( 'Calendar'[Month/Year] ) ),
                [Sales]
            )
    )
VAR _ADDRANK =
    ADDCOLUMNS (
        _SUMMARIZE,
        "RANKX",
            RANKX (
                FILTER ( _SUMMARIZE, [Month/Year] = EARLIER ( [Month/Year] ) ),
                [Sum],
                ,
                DESC,
                DENSE
            )
    )
RETURN
    SUMX (
        FILTER (
            _ADDRANK,
            [Month/Year] = MAX ( 'Calendar'[Month/Year] )
                && [Customer] = MAX ( 'Table'[Customer] )
        ),
        [RANKX]
    )

Add this measure into visual level filter and set it to show items when value <=6.

vrzhoumsft_0-1696410527757.png

 

Best Regards,
Rico Zhou

 

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

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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