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 ()
)
 

Some videos you may like

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"

gazpage

Active Member
Joined
Apr 17, 2015
Messages
393
Have you tried wrapping the SUMMARIZE() in a CALCULATETABLE()? So

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

monsoonnut

New Member
Joined
Jul 1, 2016
Messages
13
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] )
)
 

Watch MrExcel Video

Forum statistics

Threads
1,101,925
Messages
5,483,735
Members
407,406
Latest member
ishipra

This Week's Hot Topics

  • Finding issue in If elseif else with For each Loop
    Finding issue in If elseif else with For each Loop I have tried this below code but i'm getting in Y column filled with W005. Colud you please...
  • MsgBox Error
    Hi Guys, I have the below error show up when i try and run my macro in File1 but works fine if i copy and paste the same code into file2. [ATTACH...
  • CELL FORMAT - IF CONDITION
    My Cell Format is [B]""0.00" Cr". [/B]But in the cell, it is showing 123.00 for editing. (123 is entry figure). (Data imported from other...
  • Show numbers nearly the same
    Is this possible. I have a number that can change very time eg 0.00001234 Then I have a lot of numbers 0.0000001, 0.0000002, 0.00000004...
  • Please i need your help to create formula
    I need a formula in cell B8 to do this >>if b1=1 then multiply ( cell b8) by 10% ,if b1=2 multiply by 20%,if=3 multiply by 30%. Thank you in...
  • Got error while adding column and filter
    Got error while adding column and filter In column Z has some like "Success" and "Error". I want to add column in AA if the Z cell value is...
Top