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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
Anonymous
Not applicable

Count and sum by creating groups/bins filtered on date

Hi ,

 

Below mentioned is a sample data. I need to create grouping / bin and show count of name and sum in each group based on date filter selected on any 1 particular date.

DateNameSum
01-01-2020A29
01-01-2020A20
01-01-2020B25
01-01-2020C9
01-01-2020D11
02-01-2020A30
02-01-2020B27
02-01-2020C4
02-01-2020C2
02-01-2020D2
02-01-2020D20
02-01-2020E27

 

This is the expected output for any 1 date that I can select using date filter.

 

01-01-2020  
 CountSum
0-20220
21-40125
41-60149
61+00
   
02-01-2020  
 CountSum
0-2016
21-404106
41-6000
61+00

 

Any suggestion how to achieve this?

 

I tried using summarize function but was not able to do.

 

Regards,

Amit Darak

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

Hi @Anonymous ,

 

You could try to achieve it through a matrix.

 

1.Create a Category table by entering data to put the range.

4.png

 

2.Create these measures.

Sum1 =
CALCULATE (
    SUM ( 'Table'[Sum] ),
    ALLEXCEPT ( 'Table', 'Table'[Date], 'Table'[Name] )
)
NewSum =
VAR _020 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 0 && [Sum1] <= 20 ) )
VAR _2140 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 21 && [Sum1] <= 40 ) )
VAR _4160 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 41 && [Sum1] <= 60 ) )
VAR _60 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 61 ) )
RETURN
    SWITCH (
        MAX ( 'Category'[Category] ),
        "0-20", IF ( ISBLANK ( _020 ), 0, _020 ),
        "21-40", IF ( ISBLANK ( _2140 ), 0, _2140 ),
        "41-60", IF ( ISBLANK ( _4160 ), 0, _4160 ),
        "61+", IF ( ISBLANK ( _60 ), 0, _60 )
    )
Count = 
VAR _020 =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Name] ),
        FILTER ( 'Table', [Sum1] >= 0 && [Sum1] <= 20 )
    )
VAR _2140 =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Name] ),
        FILTER ( 'Table', [Sum1] >= 21 && [Sum1] <= 40 )
    )
VAR _4160 =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Name] ),
        FILTER ( 'Table', [Sum1] >= 41 && [Sum1] <= 60 )
    )
VAR _60 =
    CALCULATE ( DISTINCTCOUNT ( 'Table'[Name] ), FILTER ( 'Table', [Sum1] >= 60 ) )
RETURN
    SWITCH (
        MAX ( 'Category'[Category] ),
        "0-20", IF ( ISBLANK ( _020 ), 0, _020 ),
        "21-40", IF ( ISBLANK ( _2140 ), 0, _2140 ),
        "41-60", IF ( ISBLANK ( _4160 ), 0, _4160 ),
        "61+", IF ( ISBLANK ( _60 ), 0, _60 )
    )

 

3.Create a matrix as follows.

5.png

 

4. You can filter by date through the date slicer.

7.png6.png

 

You can check more details from here.

 

 

 

 

Best Regards,

Stephen Tao

 

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
v-stephen-msft
Community Support
Community Support

Hi @Anonymous ,

 

You could try to achieve it through a matrix.

 

1.Create a Category table by entering data to put the range.

4.png

 

2.Create these measures.

Sum1 =
CALCULATE (
    SUM ( 'Table'[Sum] ),
    ALLEXCEPT ( 'Table', 'Table'[Date], 'Table'[Name] )
)
NewSum =
VAR _020 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 0 && [Sum1] <= 20 ) )
VAR _2140 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 21 && [Sum1] <= 40 ) )
VAR _4160 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 41 && [Sum1] <= 60 ) )
VAR _60 =
    CALCULATE ( [Sum1], FILTER ( 'Table', [Sum1] >= 61 ) )
RETURN
    SWITCH (
        MAX ( 'Category'[Category] ),
        "0-20", IF ( ISBLANK ( _020 ), 0, _020 ),
        "21-40", IF ( ISBLANK ( _2140 ), 0, _2140 ),
        "41-60", IF ( ISBLANK ( _4160 ), 0, _4160 ),
        "61+", IF ( ISBLANK ( _60 ), 0, _60 )
    )
Count = 
VAR _020 =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Name] ),
        FILTER ( 'Table', [Sum1] >= 0 && [Sum1] <= 20 )
    )
VAR _2140 =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Name] ),
        FILTER ( 'Table', [Sum1] >= 21 && [Sum1] <= 40 )
    )
VAR _4160 =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Name] ),
        FILTER ( 'Table', [Sum1] >= 41 && [Sum1] <= 60 )
    )
VAR _60 =
    CALCULATE ( DISTINCTCOUNT ( 'Table'[Name] ), FILTER ( 'Table', [Sum1] >= 60 ) )
RETURN
    SWITCH (
        MAX ( 'Category'[Category] ),
        "0-20", IF ( ISBLANK ( _020 ), 0, _020 ),
        "21-40", IF ( ISBLANK ( _2140 ), 0, _2140 ),
        "41-60", IF ( ISBLANK ( _4160 ), 0, _4160 ),
        "61+", IF ( ISBLANK ( _60 ), 0, _60 )
    )

 

3.Create a matrix as follows.

5.png

 

4. You can filter by date through the date slicer.

7.png6.png

 

You can check more details from here.

 

 

 

 

Best Regards,

Stephen Tao

 

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

@Anonymous - Create a calculated column like this:

 

Column =
  SWITCH(TRUE(),
    [Sum]<=20,"0-20",
    [Sum]>20 && [Sum]<=40,"21-40",
    [Sum]>40 && [Sum]<=60,"41-60",
    "61+"
  )

Then you can use this column in a visual and use default aggregations.

 



Follow on LinkedIn
@ 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!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

@Greg_Deckler  - It does not give the output as expected. 

@Anonymous Can you be more specific?



Follow on LinkedIn
@ 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!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Jan NL Carousel

Fabric Community Update - January 2025

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