Remove filter from results of SUMMARIZE

monsoonnut

New Member
Joined
Jul 1, 2016
Messages
13
I have created a measure to look at the top 500 SKUs (by forecast) which are then bucketed into forecast unit volume groups returning count of SKU. The measure works at company level but when a hierarchical range slicer is included on my pivot, this slicer also acts on the summarize function to only return the top 500 of the selected range rather than the top 500 at company. Is there a way I can always return the Top 500 by company excluding this slicer but still include all other filters i.e. dates. This is in Powerpivot not PowerBI.

The measure is
Top 500 :=
IF (
ISFILTERED ( 'Fcst Buckets'[Bucket Name] ),
CALCULATE (
[Count of SKU],
FILTER (
TOPN (
500,
SUMMARIZE (
'Error by week,
'Error by week’[SKU],
"fcst", [Forecast]
),
[Forecast], DESC
),
COUNTROWS (
FILTER (
'Fcst Buckets',
[Forecast] >= 'Fcst Buckets'[Start]
&& [Forecast] <= 'Fcst Buckets'[end]
)
)
> 0
)
),
BLANK ()
)
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Have you tried wrapping the SUMMARIZE() in a CALCULATETABLE()? So

CALCULATETABLE (
SUMMARISE ( [ ] ),
ALL ( SlicerTable[SlicerColumn] )
)
 
Upvote 0
Thank you!! These things are always so simple when you have the answer. I also added an ALLEXCEPT within the calculate and the formula is just as I require:
F (
ISFILTERED ( 'Fcst Buckets'[Bucket Name] ),
CALCULATE (
[Count of SKU],ALLEXCEPT(RangeTable,RangeTable[RangeName]),
FILTER (
TOPN (
500,
CALCULATE TABLE(SUMMARIZE (
'Error by week,
'Error by week’[SKU],
"fcst", [Forecast]
),ALL(RangeTable)),
[Forecast], DESC
),
COUNTROWS (
FILTER (
'Fcst Buckets',
[Forecast] >= 'Fcst Buckets'[Start]
&& [Forecast] <= 'Fcst Buckets'[end]
)
)
> 0
)
),
BLANK ()
)
Have you tried wrapping the SUMMARIZE() in a CALCULATETABLE()? So

CALCULATETABLE (
SUMMARISE ( [ ] ),
ALL ( SlicerTable[SlicerColumn] )
)
 
Upvote 0

Forum statistics

Threads
1,224,885
Messages
6,181,588
Members
453,055
Latest member
cope7895

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top