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
will4444
New Member

How to create a column for revenue bands that will aggregate based on slicer view?

Hi,

 

I am trying to create a column that groups revenue into bands, which will then be able to be used as slicers. I initially used this to create these revenue groupings:

 

each if [Revenue] <= 25000 then "Under 25K" else if [Revenue] >25000 and [Revenue] <50000 then "25K-30K" else if [Revenue] >50000 and [Revenue] <100000 then "50K-100K" else if [Revenue]>100000 and [Revenue] <250000 then "100K-250K" else null)

 

It worked when looking at each product individually, but when I would look at an aggregate view for customers or month, it would be inaccurate. See below:

will4444_0-1599686144999.png

 

 

How can I create a dynamic column for revenue groups that will automatically aggregate based off of month or customer?

1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @will4444 ,

Create a single slicer table like this:

slicer.png

Create a sum total measure and a control measure, put the control measure in the visual filter and set its value as 1:

Total = 
CALCULATE (
    SUM ( 'Table'[Total Sales] ),
    ALLEXCEPT ( 'Table', 'Table'[Month], 'Table'[Customer] )
)

Control = 
VAR tab =
    ADDCOLUMNS (
        DISTINCT ( 'Slicer' ),
        "Min",
            SWITCH (
                [Slicer],
                "Under 25K", 0,
                "25K-30K", 25000,
                "50K-100K", 50000,
                "100K-250K", 100000
            ),
        "Max",
            SWITCH (
                [Slicer],
                "Under 25K", 24999,
                "25K-30K", 30000,
                "50K-100K", 100000,
                "100K-250K", 250000
            )
    )
RETURN
    IF (
        COUNTROWS ( FILTER ( tab, [Total] >= [Min] && [Total] < [Max] ) ) > 0,
        1,
        0
    )

tab.png

Attached a sample file in the below, hopes to help you.

 

Best Regards,
Yingjie Li

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

3 REPLIES 3
v-yingjl
Community Support
Community Support

Hi @will4444 ,

Create a single slicer table like this:

slicer.png

Create a sum total measure and a control measure, put the control measure in the visual filter and set its value as 1:

Total = 
CALCULATE (
    SUM ( 'Table'[Total Sales] ),
    ALLEXCEPT ( 'Table', 'Table'[Month], 'Table'[Customer] )
)

Control = 
VAR tab =
    ADDCOLUMNS (
        DISTINCT ( 'Slicer' ),
        "Min",
            SWITCH (
                [Slicer],
                "Under 25K", 0,
                "25K-30K", 25000,
                "50K-100K", 50000,
                "100K-250K", 100000
            ),
        "Max",
            SWITCH (
                [Slicer],
                "Under 25K", 24999,
                "25K-30K", 30000,
                "50K-100K", 100000,
                "100K-250K", 250000
            )
    )
RETURN
    IF (
        COUNTROWS ( FILTER ( tab, [Total] >= [Min] && [Total] < [Max] ) ) > 0,
        1,
        0
    )

tab.png

Attached a sample file in the below, hopes to help you.

 

Best Regards,
Yingjie Li

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

Greg_Deckler
Super User
Super User

@will4444 - That should have done it if you ended up with those values in a column in Power Query. You should just be able to use that column in a slicer and pick the right aggregation, Sum, Count, etc.

 

Are you saying that you need this dynamically so that you calculate the total with some additional filters and then decide what bucket it is in? You could do that with a disconnected table trick for your slicer In general, to use a measure in that way, you need to use the Disconnected Table Trick as this article demonstrates: https://community.powerbi.com/t5/Community-Blog/Solving-Attendance-with-the-Disconnected-Table-Trick...


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
amitchandak
Super User
Super User

@will4444 , Do you need this on Aggregated values or Row level values. On row level you can use Switch and do.

On Aggregated values, you need to do binning and segmentation. In that case, you need an independent table and then create a formula using that. That table needs to have buckets with limits.

 

Refer if these example can help

https://www.daxpatterns.com/dynamic-segmentation/
https://www.daxpatterns.com/static-segmentation/
https://www.poweredsolutions.co/2020/01/11/dax-vs-power-query-static-segmentation-in-power-bi-dax-po...
https://radacad.com/grouping-and-binning-step-towards-better-data-visualization

 

 

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.