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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
Power_BI_User_
Frequent Visitor

Group by the results of a grouped table variable

Hello,
I have a table, "prem_incs", of the following form:

premise_numberincident_yearjob_id
10020201
10220202
10420203
10220204
106

2020

5
10820206
10620207
10320208
10520209
108202010
102202011
101202012
105202013
105202014
109202015
105202016
103202017
108202018
107202019
106202020

 

I have created the following table variable, "first_grouping", which hopefully counts premise_number occurences by whatever year filter context is applied to it:

 

 

 

first_grouping = addcolumns(
    groupby(
        prem_incs,
        prem_incs[incident_year],
        prem_incs[premise_number]
    ),
    "prem_counts", calculate(count(prem_incs[job_id]))
)

 

 

 

It produces a table like the following, which appears correct:

prem_countspremise_number
1100
3102
1104
3106
3108
2103
4105
1101
1109
1107

 

However, when I try to then group this table a second time by prem_counts, I don't seem to be able to achieve the result I'm seeking.

Here's the dax code that I've attempted:

 

 

overall_grouping = 
var first_grouping = addcolumns(
    groupby(
        prem_incs,
        prem_incs[incident_year],
        prem_incs[premise_number]
    ),
    "prem_counts", calculate(count(prem_incs[job_id]))
)

return addcolumns(
    groupby(
        first_grouping,
        [prem_counts]
    ),
    "bins", calculate(countx(first_grouping, [premise_number]))
)

 

 

 

Here's the result the dax returns:

prem_countsbins
110
210
310
410

 

And here's the result I desire:

prem_countsbins
15
23
31
4

1

 

What should I do differently to be able to perform this grouping? My goal is to ultimately to be able to use filters remove job_id values from consideration and then to dynamically recalculate the bin numbers per year for visuals.

 

Any and all help is appreciated; thanks!


(My goal for the output visual is someting like the following):

Power_BI_User__0-1677006249182.png

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

I am not sure if I understood your question correctly, but please check the below picture and the attached pbix file.

It is for creating a new table.

 

Jihwan_Kim_0-1677039356419.png

 

 

New Table = 
VAR _firstgroup =
    ADDCOLUMNS (
        SUMMARIZE ( prem_incs, prem_incs[incident_year], prem_incs[premise_number] ),
        "@premise_count", CALCULATE ( DISTINCTCOUNT ( prem_incs[job_id] ) )
    )
VAR _secondgroup =
    GROUPBY (
        _firstgroup,
        prem_incs[incident_year],
        [@premise_count],
        "@countbins", SUMX ( CURRENTGROUP (), 1 )
    )
RETURN
    _secondgroup

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.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

View solution in original post

3 REPLIES 3
Jihwan_Kim
Super User
Super User

Hi,

I am not sure if I understood your question correctly, but please check the below picture and the attached pbix file.

It is for creating a new table.

 

Jihwan_Kim_0-1677039356419.png

 

 

New Table = 
VAR _firstgroup =
    ADDCOLUMNS (
        SUMMARIZE ( prem_incs, prem_incs[incident_year], prem_incs[premise_number] ),
        "@premise_count", CALCULATE ( DISTINCTCOUNT ( prem_incs[job_id] ) )
    )
VAR _secondgroup =
    GROUPBY (
        _firstgroup,
        prem_incs[incident_year],
        [@premise_count],
        "@countbins", SUMX ( CURRENTGROUP (), 1 )
    )
RETURN
    _secondgroup

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.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

This solution worked perfectly for me - thank you for your help!

amitchandak
Super User
Super User

@Power_BI_User_ , You should use current group by

 

example

return
groupby(
first_grouping,
[prem_counts],
"bins", calculate(countx(CURRENTGROUP(), [premise_number]))
)

 

refer for options

https://medium.com/@amitchandak/power-bi-power-query-vs-dax-append-and-summarize-data-233f173d0839

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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