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
mbagwan
Frequent Visitor

Quartile Calculation

Can someone please help me to calculate

 

Percentage of customers that contribute the 1st quartile (top 25%) of revenue 
Percentage of customers that contribute the 2nd quartile (25%-50%) of revenue
Percentage of customers that contribute the 3rd quartile (50%-75%) of revenue
Percentage of customers that contribute the 4rd quartile (75%-100%) of revenue  
 
Basically, I need to show a bar chart which will display 4 bars for each quartile as mentioned above.
 
Thanks
1 ACCEPTED SOLUTION
v-alq-msft
Community Support
Community Support

Hi, @mbagwan 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

a1.png

 

Quartile:

a2.png

 

You may create a measure as below.

Percentage = 
var total = CALCULATE(DISTINCTCOUNT('Table'[CustomerID]),ALL('Table'))
var tab = 
ADDCOLUMNS(
    ALL('Table'),
    "Rank",
    RANKX(
        ALL('Table'),
        [Revenue Contribution],,ASC
    )
)
var newtab = 
SUMMARIZE(
    Quartile,
    Quartile[Quartile],
    "Count",
    SWITCH(
        [Quartile],
        "quartile1",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=1&&[Rank]<total*0.25
                )
            ),
            total
        ),
        "quartile2",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=total*0.25&&[Rank]<total*0.5
                )
            ),
            total
        ),
        "quartile3",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=total*0.5&&[Rank]<total*0.75
                )
            ),
            total
        ),
        "quartile4",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=total*0.75&&[Rank]<=total            )
            ),
            total
        )
    )
)
return
SUMX(
    newtab,
    [Count]
)

 

Result:

a3.png

 

Best Regards

Allan

 

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

5 REPLIES 5
Ashish_Mathur
Super User
Super User

Hi,

Please share some data to work with.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
v-alq-msft
Community Support
Community Support

Hi, @mbagwan 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

a1.png

 

Quartile:

a2.png

 

You may create a measure as below.

Percentage = 
var total = CALCULATE(DISTINCTCOUNT('Table'[CustomerID]),ALL('Table'))
var tab = 
ADDCOLUMNS(
    ALL('Table'),
    "Rank",
    RANKX(
        ALL('Table'),
        [Revenue Contribution],,ASC
    )
)
var newtab = 
SUMMARIZE(
    Quartile,
    Quartile[Quartile],
    "Count",
    SWITCH(
        [Quartile],
        "quartile1",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=1&&[Rank]<total*0.25
                )
            ),
            total
        ),
        "quartile2",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=total*0.25&&[Rank]<total*0.5
                )
            ),
            total
        ),
        "quartile3",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=total*0.5&&[Rank]<total*0.75
                )
            ),
            total
        ),
        "quartile4",
        DIVIDE(
            COUNTROWS(
                FILTER(
                    tab,
                    [Rank]>=total*0.75&&[Rank]<=total            )
            ),
            total
        )
    )
)
return
SUMX(
    newtab,
    [Count]
)

 

Result:

a3.png

 

Best Regards

Allan

 

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

Hi, please note that the CustomerID and Revenue are in two different tables as per my data.

Could you please help on that

amitchandak
Super User
Super User

I tried but that's not working

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.