PowerPivot count measure

RedAero

New Member
Joined
Nov 15, 2017
Messages
3
Hi!

I've got a question that is fairly hard to describe (hence the topic title) and impossible to google for, so I'm forced to turn to the experts... Bear with me while I paint the picture.

First and foremost: I'm using Excel 2013.

I've got a large table, couple thousand rows by a hundred or so columns, which contains what can best be described as order lines: when, who, what, to whom, how, that sort of stuff. Every line has 5 KPI metric columns on the end, defined by formulas, and they can all be one of 5 values, like Open, SLA met, SLA not met, etc. So 5 columns, each with one of about 5 values for each row. Among the 100+ columns there are of course some that describe geographical location, some have various timestamps, and many other fields which would be useful to filter by. The end goal of my efforts is to create a sort-of scorecard which can be used to analyze this data, slice and group the KPIs in different ways, and the aggregation method would be to count the distinct Row IDs (a column in the data) using any given grouping of the data.

Something like this, in a nutshell:

Row IDCountryYearMonthKPI1KPI2
1US201701MetMet
1US201701Not MetMet
2GER201702MetNot Met
3UK201612Met0

<tbody>
</tbody>


One way to do this, which gets basic results but is static, is to import the table into the Data Model, create one pivot table for every KPI metric by pulling it into either the rows or columns field, and as values selecting the Distinct Count aggregation method on the Row ID field. The problem with this is that all the relevant data is spread over 5 different pivot tables which can't all be modified together if I, say, want to change the grouping I use.

So I thought "There must be a way to create one measure per KPI in PowerPivot, and then I can just use them as the Values with only the actual grouping in the rows and columns! All I need is a measure that somehow takes the Row/Column filter context (i.e. whatever the last filter in the Pivot Table is) and filters only the specific KPI field, then counts the distinct Row IDs." Question is: how?

One way which does work, but is pretty awkward, is to create one measure per KPI value, not field: =CALCULATE(DISTINCTCOUNT(Table[Row ID]), Table[KPI1]="Met"), =CALCULATE(DISTINCTCOUNT(Table[Row ID]), Table[KPI1]="Not Met"), =CALCULATE(DISTINCTCOUNT(Table[Row ID]), Table[KPI2]="Met"), etc.
Then I can just drag all these to the Values section and I'm done. Problem is, if I want to change the KPI functions to return, say, "Pass" instead of "Met", I have to change the measures too... So is there a way to create just ONE measure per KPI which will do the trick? To effectively make the "Met", "Not Met", etc. part of those measures above dynamic?

As I thought about the problem I kept going back and forth between "Surely this must be possible" and "Does this even make sense? Can it even be done conceptually?", so I won't be too surprised if the straightforward solution above ends up being the only one, but my gut tells me that with some combination of CALCULATE and FILTER and ALL it might be possible. In any case, I hope someone here will be able to put the issue to rest one way or another.

Thanks in advance!
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
Can’t pretend I really follow your problem, but if you google “disconnected slicers dax” or something you’ll find a bunch of blogs that describe how to have a slicer change part of a measure.
 
Upvote 0
Can’t pretend I really follow your problem, but if you google “disconnected slicers dax” or something you’ll find a bunch of blogs that describe how to have a slicer change part of a measure.

Thanks, I'll look into it, but I'm not trying to use slicers. I know I didn't describe the problem in the clearest of terms, can you give me a hint as to how I can improve it? In the meantime, I'll try to simplify:


I have 5 columns (KPIs) in my data which all contain one of 5 strings as values, all of them the same values. I want to create a pivot table which displays, as rows, the 5 KPIs, and within them, the distinct row counts of the Row ID columns when filtered for the 5 values, with the possibility of grouping them based on other things as usual for a pivot table. Something a bit like the table below. The values in the table below are just examples, they have nothing to do with the table in the previous post.


KPIsValues of KPIsUSGER...
KPI1Met[Distinct Count of Row IDs where KPI1="Met" and Country="US"] = 5[Distinct Count of Row IDs where KPI1="Met" and Country="GER"] = 5...
KPI1Not Met[Distinct Count of Row IDs where KPI1="Not Met" and Country="US"] = 2......
KPI1Backlog.........
KPI1Open.........
KPI1Null.........
KPI2Met[Distinct Count of Row IDs where KPI2="Met" and Country="US"] = 4......
KPI2Not Met.........
KPI2Backlog.........
KPI2Open.........
KPI2Null.........
KPI3Met.........
KPI3Not Met.........
KPI3Backlog[Distinct Count of Row IDs where KPI2="Backlog" and Country="US"] = 12......
KPI3Open.........
KPI3Null.........
...Met.........

<tbody>
</tbody>



****** id="cke_pastebin" style="position: absolute; top: 210px; width: 1px; height: 1px; overflow: hidden; left: -1000px;">
[Distinct Count of Row IDs where KPI1="Met" and Country="US"] = 5T

<tbody>
</tbody>
</body>The only way I can currently do this is by defining a separate measure for every single KPI-Value combination (e.g. KPI2 = "Backlog", KPI3 = "Open", etc.), 25 measures in total, which will not be able to change should the values change in the future. Is there a way to make one measure per KPI?
 
Upvote 0
Well if I were you I would just create a measure:

IDCount:= DISTINCTCOUNT ( Table[Row ID] )

Drop that into a pivot table and then put country in the columns and your first KPI column in the rows. I'd then duplicate that pivot table 4 more times and change the rows to KPI 2, KPI 3 etc. Finally use standard excel to merge the results together if really necessary.
 
Last edited:
Upvote 0
Well if I were you I would just create a measure:

IDCount:= DISTINCTCOUNT ( Table[Row ID] )

Drop that into a pivot table and then put country in the columns and your first KPI column in the rows. I'd then duplicate that pivot table 4 more times and change the rows to KPI 2, KPI 3 etc. Finally use standard excel to merge the results together if really necessary.

I did mention that solution in the OP, the problem is, what if instead of country the user wants to aggregate by week? Or week and country? Now I have to modify 5 pivot tables, which is really inconvenient (or write a macro I guess, but let's not get carried away). This, by the way, is the current state of affairs which I'm trying to improve. In the meantime, as a proof of concept I've created the 25 separate measures for the 5 KPIs and 5 Values, and it works, but it's pretty clumsy.
 
Upvote 0
Well I think I finally understand what you are after now.

Suggest you use power query to unpivot the KPI columns you will end up with a two columns, one with the KPI, and another with the values. You can then drag both these columns to the rows of your pivot table, and reorder as needed.
 
Upvote 0

Forum statistics

Threads
1,213,534
Messages
6,114,188
Members
448,554
Latest member
Gleisner2

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