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

To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.

Reply
drakwen
New Member

Distribute a table between %

Hey guys,

 

What would be the best way to achieve the following example?

 

  • Desired Output - Course Engagement distribution
     Count of Unique Employees
    0%-25%10
    25%-50%15
    50%-75%55
    75%-99%25
    100%10

 

  • Source (I don't want to add any calculated columns here since it's a 1.5M row table with 20 columns)
    UniqueIDCourseIDStatus
    g5hfg6hg54sadad223Completed
    g5hfg6hg54asda3166Not Started
    as6d54a6s54asda3166Completed
    as5d6asd566asda1656Not Started
    dsd6f45d677dsada215Not Started

 

  • So, to calculate engagement what we do is:  Tot al Completed Courses / Total Assigned Coursed, which would return as this:
    • g5hfg6hg54 1 Completed / 2 Total = 50%
    • as6d54a6s54 1 Completed / 1 Total = 100%
    • as5d6asd566 1 Not Started / 1 Total = 0%
    • dsd6f45d677 1 Not Started / 1 Total = 0%

 

  • Final table on example is 
     Count of Unique Employees
    0%-25%2
    25%-50% 
    50%-75%1
    75%-99% 
    100%1

 

Many many thanks in advance,

AC.

2 ACCEPTED SOLUTIONS
FreemanZ
Super User
Super User

@drakwen 

 

Are you expecting something like this:

FreemanZ_0-1668310778875.png

 

It hides some complexity, we would need to create a segment table like below:

FreemanZ_1-1668310831901.png

Based on the Segment table and the orginal Data table, we could get your expected table with a calculated table with the code below:

 

SegmentCount =
VAR _table =
ADDCOLUMNS(
    SUMMARIZE (Data, Data[UniqueID]),
    "PctCount",
    VAR CompleteCount =
        CALCULATE (
            COUNTROWS(
                FILTER(Data, Data[Status] = "Completed")
            )
        )
    VAR TotalCount =
    CALCULATE (
           COUNTROWS(Data),
           ALLEXCEPT(Data, Data[UniqueID])
     )
    RETURN
        DIVIDE (CompleteCount, TotalCount, 0 )
)

RETURN
ADDCOLUMNS(
    Segment,
    "Count of Unique Employees",
        COUNTROWS(
         FILTER (
            _table,
            AND ([PctCount]>=Segment[Min], [PctCount]<Segment[Max])
        )
    )
)

View solution in original post

Anonymous
Not applicable

Hi @drakwen ,

Looking forward to your next reply. If you validate that the method provided by @FreemanZ and @amitchandak can help you get the solution later, could you please mark it as Answered? It will help the others in the community find the solution easily if they face the same problem as yours. Thank you.

Best Regards

View solution in original post

5 REPLIES 5
FreemanZ
Super User
Super User

@drakwen 

 

Are you expecting something like this:

FreemanZ_0-1668310778875.png

 

It hides some complexity, we would need to create a segment table like below:

FreemanZ_1-1668310831901.png

Based on the Segment table and the orginal Data table, we could get your expected table with a calculated table with the code below:

 

SegmentCount =
VAR _table =
ADDCOLUMNS(
    SUMMARIZE (Data, Data[UniqueID]),
    "PctCount",
    VAR CompleteCount =
        CALCULATE (
            COUNTROWS(
                FILTER(Data, Data[Status] = "Completed")
            )
        )
    VAR TotalCount =
    CALCULATE (
           COUNTROWS(Data),
           ALLEXCEPT(Data, Data[UniqueID])
     )
    RETURN
        DIVIDE (CompleteCount, TotalCount, 0 )
)

RETURN
ADDCOLUMNS(
    Segment,
    "Count of Unique Employees",
        COUNTROWS(
         FILTER (
            _table,
            AND ([PctCount]>=Segment[Min], [PctCount]<Segment[Max])
        )
    )
)

Hi @FreemanZ and @amitchandak 


I tried both your methods and both return the samer result, two equal results split into two ranges 25%-50% and 75%-99% for 297. I know that my actual result should be around 6k, so I will try this week to limit the database to 1000 results and play until I discover what is going on with my data, because I am pretty sure both your answers are correct.

 

Many thanks for both your replies, I'll keep you posted.

Anonymous
Not applicable

Hi @drakwen ,

Looking forward to your next reply. If you validate that the method provided by @FreemanZ and @amitchandak can help you get the solution later, could you please mark it as Answered? It will help the others in the community find the solution easily if they face the same problem as yours. Thank you.

Best Regards

I confirm it now works!! It was my data that was failing

amitchandak
Super User
Super User

@drakwen , You need dynamic segmentation for that

 

Divide( Count(filter(Table[Status] ="Completed"), Table[CourseID]) , Count(Table[CourseID]) )

 

Dynamic Segmentation Bucketing Binning
https://community.powerbi.com/t5/Quick-Measures-Gallery/Dynamic-Segmentation-Bucketing-Binning/m-p/1...


Dynamic Segmentation, Bucketing or Binning: https://youtu.be/CuczXPj0N-k

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
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 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.