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
Anonymous
Not applicable

Calculations on Summarized columns

Hello, 

 

     Reading/Watching articles, questions, I learnt about Summarize and found it appropriate for my usage. Am stuck at a point. Hope some one could help me.

 

My original data is :

Call DateCall YearCall MonthMonth NameMonthPMNMoUMBTMD.COUNTRYStd Target 
1/1/20212021202101Jan1ALBEM0.0833330Albania0% 
1/1/20212021202101Jan1ALBVF173.51671251.777Albania100% 
1/1/20212021202101Jan1ALBAM10.716670Albania0% 
1/1/20212021202101Jan1ALBVF623.016729903.94Albania100% 
1/1/20212021202101Jan1ALBAM 4935.924Albania0% 
1/1/20212021202101Jan1ALBAM 0Albania0% 
1/1/20212021202101Jan1ALBAM 0Albania0% 

There are more dates.

 

I want is - 1) total of MB for each PMN of each Date.  2) Total of MB for each Country of each Date  3) Divide the TotalByCountry / TotalPerPMN and save it as a percentage.

 

I started up with a Summarize table:

 

 

Summary_MB = 
    SUMMARIZE(OutboundVolumes,
    OutboundVolumes[Call Date], 
    OutboundVolumes[TMDPartners.COUNTRY],
    OutboundVolumes[PMN (SYN)],
    "TotalMBs", SUM(OutboundVolumes[Real Volume (MB)]), 
    "TotalMoUs", SUM(OutboundVolumes[Real MoU])
) 

 

This gives me my (1) total of MB for each PMN of each Date

td_beginner_0-1629326399732.png

 

For Total for each Country by Date, I need to GroupBy CallDate, & Country, and SUM(TotalMBs). I couldn't figure out to do this part in the above Summarize command, so made another table (though wanted in the same table Summary_MB 😞 😞

 

Summary_MB_Country = 
    SUMMARIZE(Summary_MB,
    Summary_MB[Call Date], 
    Summary_MB[TMDPartners.COUNTRY],
    "TotalMBsPerCountrty", SUM(Summary_MB[TotalMBs])
)

 

And this gives me perfect result:

td_beginner_1-1629326708157.png

 

I did get the sum of MB column for each PMN & Country based on Date - though they both are in different tables.

 

Now, I got to divide 

Summary_MB_Country[TotalMBsPerCountrty] /  Summary_MB[TotalMBs]  
for each country based on date and store the value in a column. 

Tried Addcolumn in the Summary_MB table, Add measure, but nothing gives the expected results. Expected result is :

DateALBAMALBEMALBVFGrand TotalALBAM %ALBEM %ALBVF  %
1/1/2021493603115636091.6414%0%86%

 

Can anyone here help me figure out how do I accomplish this.

Any help is appreciated.

 

Thank you

1 ACCEPTED SOLUTION
AllisonKennedy
Super User
Super User

@Anonymous  I see no one has come back with a more detailed reply and I have a bit more time now, so please see attached pbix file below my signature. 

 

I have created Dimension tables for your for Date, Country and PMN as this will make your life easier in the long run. I referenced the OutboundVolumes table to generate these (see my video on survey data for something similar) but ideally you'd have this in your data source already and can pull into Power BI. 

 

Then I created a simple measure for Total MB:

 

Total MB = SUM(OutboundVolumes[MB])
 
Then I created a measure to get Total MB for ALL PMN (when you configure the visual correctly this will give you the total per Country and Date); 
 
Total MB all PMN =
IF([Total MB] <> BLANK(),
CALCULATE([Total MB], All(PMN))
)
 
Finally, I divided these: 
 
% of MB by Total MB all PMN = DIVIDE([Total MB], [Total MB all PMN])
 
Using the Matrix visual, you have your desired column: 
 
AllisonKennedy_1-1629365967573.png

 


 

 

Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

View solution in original post

8 REPLIES 8
AllisonKennedy
Super User
Super User

@Anonymous  I see no one has come back with a more detailed reply and I have a bit more time now, so please see attached pbix file below my signature. 

 

I have created Dimension tables for your for Date, Country and PMN as this will make your life easier in the long run. I referenced the OutboundVolumes table to generate these (see my video on survey data for something similar) but ideally you'd have this in your data source already and can pull into Power BI. 

 

Then I created a simple measure for Total MB:

 

Total MB = SUM(OutboundVolumes[MB])
 
Then I created a measure to get Total MB for ALL PMN (when you configure the visual correctly this will give you the total per Country and Date); 
 
Total MB all PMN =
IF([Total MB] <> BLANK(),
CALCULATE([Total MB], All(PMN))
)
 
Finally, I divided these: 
 
% of MB by Total MB all PMN = DIVIDE([Total MB], [Total MB all PMN])
 
Using the Matrix visual, you have your desired column: 
 
AllisonKennedy_1-1629365967573.png

 


 

 

Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

Anonymous
Not applicable

wow, great @AllisonKennedy . Thanks a lot. 

Your detailed explaination and pibx file help me achieve this big requirement (for me 🙂 ).

Your blog  is also great, has so much detail. 

 

I want to show the PMNs with 0 Total MB/Total MB all PMN of a Country. I tried the IF clauses, but that brings up all the PMNs. Any way that we can show up 0% for any of the Total is 0 or blank.

 

Thanks a lot. 

I highly appreciate your guidance and support.

 

 

@Anonymous You're welcome. 

 

In order to show 0% you will either get all PMNs displayed as you have already discovered, or you need to specify which PMNs you want to see somehow. Can you explain this in further detail? 

 

Other option would be to use Power Query - so click 'Transform Data' to open Power Query, then in the Tranform tab > Replace values. Replace null with 0. 

This will then carry through to the formula.


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

Anonymous
Not applicable

Hello @AllisonKennedy , 

 

     There are few nulls in Country field, which I have filtered out. 

      The see the issue - the OutboundVolume is merged with TMD table that gives Country. TMD contains all PMNs which may not be in the OutboundVolumes. Those PMNs, even if merged with OutboundVolumes, would contain no data for Dates, MB, or any relevant field. On by filtering Date, dataset could not have those PMNs, as the value for CallDate is null.

Doing a Left Join, I have grabbed the Country and Std Target from the TMD into OutboundVolumes.

 

It's like, "ALBEM" is for 1/1/21, but not for 1/2/21, so for 1/2/21, it doesn't show ALBEM. 

Call DateCall YearCall MonthMonth NameMonthPMNMoUMBTMD.COUNTRYTMD.Std Target
1/1/20212021202101Jan1ALBEM0.0833330Albania0%
1/1/20212021202101Jan1ALBVF173.51671251.777Albania100%
1/1/20212021202101Jan1ALBAM10.716670Albania0%
1/1/20212021202101Jan1ALBVF623.016729903.94Albania100%
1/1/20212021202101Jan1ALBAM 4935.924Albania0%
1/1/20212021202101Jan1ALBAM 0Albania0%
1/1/20212021202101Jan1ALBAM 0Albania0%
1/2/20212021202101Jan1ALBVF353.810586.44Albania100%
1/2/20212021202101Jan1ALBAM25.3333312.27256Albania0%
1/2/20212021202101Jan1ALBVF314.624669.91Albania100%
1/2/20212021202101Jan1ALBAM 3019.622Albania0%
1/2/20212021202101Jan1ALBAM 147.5871Albania0%
1/2/20212021202101Jan1ALBAM 0Albania0%
1/2/20212021202101Jan1ALBAM 0Albania0%

  

The Country & Std Target taken from TMD contains:

PMNCountryTarget
ALBEMAlbania0%
ALBVFAlbania5%
ALBAMAlbania95%

 

Could we possibly show all the partners from the TMD for each date regardless of the data being available in the OutboundVolumes. If there is no data, then we show 0.

 

Hope this helps.

 

Thank You, 

 

 

@Anonymous  Can you please share a screenshot of your model view? You're on the right track with a Left Outer join - I'm just a bit lost with all the tables and abbreviations you mentioned, so need the model view to visualize what we're working with please. 🙂 


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

Anonymous
Not applicable

Hello @AllisonKennedy 

 

My Model diagram:

td_beginner_2-1630019656768.png

 

td_beginner_3-1630019696880.png

 

By Creating the PMN table from TMD[PMN], I could atleast show all PMN in the dropdown list, but doesn't show in the chart or the Matrix.

3 PMN for Albania country are - ALBAM, ALBEM, and ALBVF

td_beginner_1-1630019157422.png

 

Thank you

Ashish_Mathur
Super User
Super User

Hi,

Why are you creating a calculated table?  A calculated table does not respond to a change in slicers?  Why not write measures and drag those to your visual?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
AllisonKennedy
Super User
Super User

@Anonymous  Do you have a DimDate and DimCountry table? 

https://excelwithallison.blogspot.com/2020/08/its-complicated-relationships-in-power_11.html 

I would suggest using the CALCULATE and ALL functions to get the total per date and country, as MEASURES, then just do a simple DIVIDE function to get the percent. 


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

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.