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

SUMMARIZECOLUMNS question

Hello

I am creating a table using SUMMARIZECOLUMNS.

My original data looks as follows -

 

All_Data.JPG

 

As you can see, there is only 1 category under India.

 

My table DAX created using SUMMARIZECOLUMNS is as follows -

 

SummarizeTable = SUMMARIZECOLUMNS ( ListOfOrders[Country], OrderBreakdown[Category],FILTER('ListOfOrders', 'ListOfOrders' [Country] = "India") )
 
And its output is as follows -
SummarizeColumnsOutput.JPG
 
However, as per this output, I am seeing all categories under India which is incorrect.
 
What could be the reason for this?
 
Regards
1 ACCEPTED SOLUTION
jdbuchanan71
Super User
Super User

Hello @Anonymous 

SUMMARIZECOLUMNS without a calcualted value performs a CROSSJOIN on the columns and has no way to apply a filter to limit the returned rows (It doesn't know there is no data for India - Technology).

You can use summarize over the detail table then feed in the higher level columns and it will only return values that are represented in the lower level table.  Something like

SummarizeTable =
CALCULATETABLE (
    SUMMARIZE ( OrderBreakdown, ListOfOrders[Country], OrderBreakdown[Category] ),
    'ListOfOrders'[Country] = "India"
)

This code assumes OrderBreakdown is the bigger detail table and ListOfOrders is joined to it as the 1 side of a *:1

 

As and example, this code would give me all of the Subcategory values that are represented in the Sales table and leave out any that are not.

Table = SUMMARIZE(Sales,'Product Subcategory'[Subcategory])

View solution in original post

1 REPLY 1
jdbuchanan71
Super User
Super User

Hello @Anonymous 

SUMMARIZECOLUMNS without a calcualted value performs a CROSSJOIN on the columns and has no way to apply a filter to limit the returned rows (It doesn't know there is no data for India - Technology).

You can use summarize over the detail table then feed in the higher level columns and it will only return values that are represented in the lower level table.  Something like

SummarizeTable =
CALCULATETABLE (
    SUMMARIZE ( OrderBreakdown, ListOfOrders[Country], OrderBreakdown[Category] ),
    'ListOfOrders'[Country] = "India"
)

This code assumes OrderBreakdown is the bigger detail table and ListOfOrders is joined to it as the 1 side of a *:1

 

As and example, this code would give me all of the Subcategory values that are represented in the Sales table and leave out any that are not.

Table = SUMMARIZE(Sales,'Product Subcategory'[Subcategory])

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.