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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Nandor
Helper I
Helper I

Sum only Distinct values in PowerBI Report bar chart

Dear All,

 

I have a database that contains the date, the activity name and the minutes that activity lasted:

 

Activity_StartTimeActivity_NameActivity_Duration_Minutes
09/08/2016 15:01Activity 145
09/08/2016 15:01Activity 145
10/08/2016 16:46Activity 130
10/08/2016 16:46Activity 130
10/08/2016 16:46Activity 130
11/08/2016 19:00Activity 120
11/08/2016 19:00Activity 120

 

I would need a bar chart.

On the X axes I would like to have the year and

on the Y axes I would need the number of minutes of the activity.

 

In this case the hight of the bar should be 45+30+20=95

 

Thank you for picking up this challenge.

2 ACCEPTED SOLUTIONS
samdthompson
Memorable Member
Memorable Member

Hi, welcome to the community. This solution assumes that there is no other data being used and that all activities have a different start time

 

1. Make a new calculated column called year to use for the x axis. in it put the DAX =year(Activity_StartTime)

2. Make a second calculated column with the DAX =divide(calculate(average(Table1[Activity_Duration_Minutes]),ALLEXCEPT(Table1,Table1[Activity_StartTime],Table1[Activity_Name])),calculate(COUNTA(Table1[Activity_StartTime]),ALLEXCEPT(Table1,Table1[Activity_StartTime],Table1[Activity_Name])),0)

3. Use the calculated column as the value in the stacked chart

 

Capture.JPG

 

 

 

// please mark as solution if it answers your question.

// if this is a solution please mark as such. Kudos always appreciated.

View solution in original post

Hi, i have formatted the DAX a little better for you:

=
DIVIDE (
    CALCULATE (
        AVERAGE ( Table1[Activity_Duration_Minutes] ),
        ALLEXCEPT ( Table1, Table1[Activity_StartTime], Table1[Activity_Name] )
    ),
    CALCULATE (
        COUNTA ( Table1[Activity_StartTime] ),
        ALLEXCEPT ( Table1, Table1[Activity_StartTime], Table1[Activity_Name] )
    ),
    0
)

 

its working it out by gouping together the numbers that share the same activity name and the same start time and dividing them by the count of how many in each group eg: average(45,45)/count(45,45) = 2 * 22.5; average(30,30,30)/count(30,30,30) = 3 * 10; average(20,20)/count(20,20) = 2 * 10. When you add that to your chart it will sum up the individual calculations.

// if this is a solution please mark as such. Kudos always appreciated.

View solution in original post

5 REPLIES 5
samdthompson
Memorable Member
Memorable Member

Hi, welcome to the community. This solution assumes that there is no other data being used and that all activities have a different start time

 

1. Make a new calculated column called year to use for the x axis. in it put the DAX =year(Activity_StartTime)

2. Make a second calculated column with the DAX =divide(calculate(average(Table1[Activity_Duration_Minutes]),ALLEXCEPT(Table1,Table1[Activity_StartTime],Table1[Activity_Name])),calculate(COUNTA(Table1[Activity_StartTime]),ALLEXCEPT(Table1,Table1[Activity_StartTime],Table1[Activity_Name])),0)

3. Use the calculated column as the value in the stacked chart

 

Capture.JPG

 

 

 

// please mark as solution if it answers your question.

// if this is a solution please mark as such. Kudos always appreciated.

Thank you, it is working as expected.

 

Best regards,

Nandor

Hi, Thank you again for the solution. I am struggling to understand the formula, could you please explaint the logics behind your script.

 

Thank you,

Nandor

Hi, i have formatted the DAX a little better for you:

=
DIVIDE (
    CALCULATE (
        AVERAGE ( Table1[Activity_Duration_Minutes] ),
        ALLEXCEPT ( Table1, Table1[Activity_StartTime], Table1[Activity_Name] )
    ),
    CALCULATE (
        COUNTA ( Table1[Activity_StartTime] ),
        ALLEXCEPT ( Table1, Table1[Activity_StartTime], Table1[Activity_Name] )
    ),
    0
)

 

its working it out by gouping together the numbers that share the same activity name and the same start time and dividing them by the count of how many in each group eg: average(45,45)/count(45,45) = 2 * 22.5; average(30,30,30)/count(30,30,30) = 3 * 10; average(20,20)/count(20,20) = 2 * 10. When you add that to your chart it will sum up the individual calculations.

// if this is a solution please mark as such. Kudos always appreciated.

Thank you!

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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