cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mjholland Regular Visitor
Regular Visitor

Sum a Measure Across 2 Layers of Categorisation, Multiple Column Headers

Hi,

 

I'm using the following DAX measure to work out if a KPI for a particular category has been achieved:

 

KPI Achieved = SUMX (
    Category,
    IF (Category[Category] = "Beverages",if([%Avg]>=1,1,0),
    IF (Category[Category] = "Confectionery Homestock",if([%Avg]>=1,1,0),
    IF (Category[Category] = "Confectionery Impulse",if([%Avg]>=1,1,0),
    IF (Category[Category] = "Food",if([%Avg]>=1,1,0),
    IF (Category[Category] = "Purina",if([%TGT]>=1,1,0),
    IF (Category[Category] = "Waters",if([% TGT]>=1,1,0),
    BLANK() )
    )
)))))

 

Each Category has a different target. I've used this function along with IF statements to see if the target is achieved for each category to highlight that with a 1. I'm then putting this measure into a table.

 

There's one added level of complexity - I need to show the results split across 2 higher categories - SS and MC, which would eventually give 12 KPIs, rathen than just 6. When I put this into the table the Total value at the end isn't the sum of all 12 categories, as follows:

 

01.PNG

 

So, for example, the second row should total to 11, not 6.

 

My Categories are in one table, my high Categories are in another and my list of IDs, on the left, is in one final table.

 

Can anyone help with this?


Thanks,

Mark

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Moderator v-sihou-msft
Moderator

Re: Sum a Measure Across 2 Layers of Categorisation, Multiple Column Headers

@mjholland

 

In your formula, it analysis on Category level only, it will not take the higher categories filter context, which means on grand total level, it will never calculate greater tha 6 since you only have 6 categories. 

 

For your requirement, you should use a summarize table to have your calculation group on higher categories (SS, MC). You can try formula like below; 

 

KPI Achieved =
SUMX (
    SUMMARIZE (
        HighCategories,
        HighCategories[HighCategories],
        "KpiCount", SUMX (
            Category,
            IF (
                Category[Category] = "Beverages",
                IF ( [%Avg] >= 1, 1, 0 ),
                IF (
                    Category[Category] = "Confectionery Homestock",
                    IF ( [%Avg] >= 1, 1, 0 ),
                    IF (
                        Category[Category] = "Confectionery Impulse",
                        IF ( [%Avg] >= 1, 1, 0 ),
                        IF (
                            Category[Category] = "Food",
                            IF ( [%Avg] >= 1, 1, 0 ),
                            IF (
                                Category[Category] = "Purina",
                                IF ( [%TGT] >= 1, 1, 0 ),
                                IF ( Category[Category] = "Waters", IF ( [% TGT] >= 1, 1, 0 ), BLANK () )
                            )
                        )
                    )
                )
            )
        )
    ),
    [KpiCount]
)

Regards,

2 REPLIES 2
Highlighted
Moderator v-sihou-msft
Moderator

Re: Sum a Measure Across 2 Layers of Categorisation, Multiple Column Headers

@mjholland

 

In your formula, it analysis on Category level only, it will not take the higher categories filter context, which means on grand total level, it will never calculate greater tha 6 since you only have 6 categories. 

 

For your requirement, you should use a summarize table to have your calculation group on higher categories (SS, MC). You can try formula like below; 

 

KPI Achieved =
SUMX (
    SUMMARIZE (
        HighCategories,
        HighCategories[HighCategories],
        "KpiCount", SUMX (
            Category,
            IF (
                Category[Category] = "Beverages",
                IF ( [%Avg] >= 1, 1, 0 ),
                IF (
                    Category[Category] = "Confectionery Homestock",
                    IF ( [%Avg] >= 1, 1, 0 ),
                    IF (
                        Category[Category] = "Confectionery Impulse",
                        IF ( [%Avg] >= 1, 1, 0 ),
                        IF (
                            Category[Category] = "Food",
                            IF ( [%Avg] >= 1, 1, 0 ),
                            IF (
                                Category[Category] = "Purina",
                                IF ( [%TGT] >= 1, 1, 0 ),
                                IF ( Category[Category] = "Waters", IF ( [% TGT] >= 1, 1, 0 ), BLANK () )
                            )
                        )
                    )
                )
            )
        )
    ),
    [KpiCount]
)

Regards,

mjholland Regular Visitor
Regular Visitor

Re: Sum a Measure Across 2 Layers of Categorisation, Multiple Column Headers

@v-sihou-msft this is perfect, it works a treat. Thank you so much.