Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Georgia_H
Helper I
Helper I

How to make distinct count value with filter as constant

Hello,

 

Need help. Here's my sample data. 

I have derived this measure to count distinct by Metrics_ID in my sample dataset, which will give me 12. I want the count to show as 12 on every row as my denominator (Unique count by Metrics_ID) instead of 1 on every row. How can i achieve that in DAX Measure?

 

Denominator =

VAR Count_PCM_denominator=CALCULATE(DISTINCTCOUNT('rep F_ITS_MetricsLanding'[Metrics_ID]),FILTER('rep F_ITS_MetricsLanding','rep F_ITS_MetricsLanding'[Metrics_ID] in {"PCM01","PCM03","PCM04","PCM09","PCM10","PCM19","PCM20","PCM23","PCM33","PCM34","PCM35","PCM36"}),ALL('rep F_ITS_MetricsLanding'[Metrics_ID],'rep F_ITS_MetricsLanding'[LBU]))

RETURN Count_PCM_denominator

 

SAMPLE DATA:

LBUMetrics_IDAvg Compliance %
EILUXPCM2360.10%
PAMCPCM0178.80%
PAMCPCM0381.30%
PAMCPCM0462.10%
PAMCPCM0956.80%
PAMCPCM1059.60%
PAMCPCM1968.60%
PAMCPCM2055.90%
PAMCPCM2385.90%
PAMCPCM3365.00%
PAMCPCM3447.80%
PAMCPCM3557.10%
PAMCPCM3662.00%
PCALKKPCM04100.00%

 

EXPECTED RESULTS:

Expected Results for EILUX  
LBUMetrics_IDAvg Compliance %Denominator (unique by Metrics_ID)Expected Compliance_Value (AVG) divided by MAX Count of Denominator i.e. 12
EILUXPCM2360.10%125.00%

 

Expected Results for PCALKK  
LBUMetrics_IDAvg Compliance %Denominator (unique by Metrics_ID)Expected Compliance_Value (AVG) divided by MAX Count of Denominator i.e. 12
PCALKKPCM04100.00%128.33%
1 ACCEPTED SOLUTION
TomMartens
Super User
Super User

Hey @Georgia_H ,

I changed the denominator and the division measure in my example. Please be aware that I only used two metrics inside both measures to create a virtual table.

The denominator now is more or less a constant:

denominator = 
var metricsToCount = {"PCM01" , "PCM23"}
var metricsCount = COUNTROWS( metricsToCount )
return metricsCount

You might expand the definition of the denominator like so

denominator check = 
var metricsToCount = {"PCM01" , "PCM23"}
var metricsCount = COUNTROWS( metricsToCount )
return 
IF( FIRSTNONBLANK( 'Table'[Metrics_ID] , 'Table'[Metrics_ID] ) in metricsToCount
    , metricsCount
    , BLANK()
)


The division measure now looks like this:

division = 
var metricsToCount = {"PCM01" , "PCM23"}
var metricsCount = COUNTROWS( metricsToCount )
return

AVERAGEX(
    'Table'
    , if( FIRSTNONBLANK( 'Table'[Metrics_ID] , 'Table'[Metrics_ID] ) in metricsToCount
        , DIVIDE( 'Table'[Avg Compliance %]  , metricsCount )
        , BLANK()
    )
) * 100

 

 The table visual looks like this:

image.png

Of course, it's possible to create a table from the 12 metrics, then you do not have to repeat the definition in both measures, but if they are just used in two measures I would probably use the measure definition.

As the metric is used inside your table, it will contribute to the current filter context, but the current filter context will not be expanded, for this reason the DISTINCTCOUNT will return 1. 

Hopefully, this will help to tackle your challenge

 

Regards,

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

View solution in original post

7 REPLIES 7
TomMartens
Super User
Super User

Hey @Georgia_H ,

I changed the denominator and the division measure in my example. Please be aware that I only used two metrics inside both measures to create a virtual table.

The denominator now is more or less a constant:

denominator = 
var metricsToCount = {"PCM01" , "PCM23"}
var metricsCount = COUNTROWS( metricsToCount )
return metricsCount

You might expand the definition of the denominator like so

denominator check = 
var metricsToCount = {"PCM01" , "PCM23"}
var metricsCount = COUNTROWS( metricsToCount )
return 
IF( FIRSTNONBLANK( 'Table'[Metrics_ID] , 'Table'[Metrics_ID] ) in metricsToCount
    , metricsCount
    , BLANK()
)


The division measure now looks like this:

division = 
var metricsToCount = {"PCM01" , "PCM23"}
var metricsCount = COUNTROWS( metricsToCount )
return

AVERAGEX(
    'Table'
    , if( FIRSTNONBLANK( 'Table'[Metrics_ID] , 'Table'[Metrics_ID] ) in metricsToCount
        , DIVIDE( 'Table'[Avg Compliance %]  , metricsCount )
        , BLANK()
    )
) * 100

 

 The table visual looks like this:

image.png

Of course, it's possible to create a table from the 12 metrics, then you do not have to repeat the definition in both measures, but if they are just used in two measures I would probably use the measure definition.

As the metric is used inside your table, it will contribute to the current filter context, but the current filter context will not be expanded, for this reason the DISTINCTCOUNT will return 1. 

Hopefully, this will help to tackle your challenge

 

Regards,

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

Hi @TomMartens 

Just a quick question, instead of hardcoding the list of Metrics in the var below, possible to check through the list of Metrics_ID that present in the table? Reason being is that some new Metrics_ID may not have data for any particular period hence, they should not be counted as 1 as my constant denominator. With this syntax, i am always getting the count of Metrics_ID hardcoded. Thank you.

var metricsToCount = {"PCM01" , "PCM23"}

 

Hey @Georgia_H ,

 

It's difficult to provide a solution that suits your needs if you do not describe your requirements completely. Make sure that the sample data you provide represents your data model (tables, relationships, calculated columns, and measures). Consider creating a pbix file that contains sample data, upload the pbix file to onedrive or dropbox and share the link. if you are using Excel to create the sample data instead of the manual input method share the xlsx as well.

Starting with the question on how to have

  • DISTiNCTCOUNT overcome the current filter context,
  • to there are metrics available that should not be considered and now
  • if metrics that should be considered have no values throughout any period (there is no period in your sample data) these metrics should be removed from the table.

It's not a good idea to change the direction of the initial question as this can confuse other users as these users will not consider this thread to find an answer to their problem.

It's better to start a new thread instead.

The general approach to finding a solution for your problem might look like this (I'm pretty sure that I miss important information):

  • define a table with all possible metrics (maybe a dimension table in your star schema data model)
  • reduce the table by removing metrics based on rules like "a metric that has no values in any period"  has to be removed, maybe this rule will transform to no value in the current year
  • use the found table to count the denominator and inside the division.

In regards to your remark that you will get the count of metrics hardcoded if you used this approach:

var metricsToCount = {"PCM01" , "PCM23"}

At the time of providing my solution I was inspired by your approach from further down this thread without knowing that metrics might be excluded due to business rules:

,,, in {"PCM01","PCM03","PCM04","PCM09","PCM10","PCM19","PCM20","PCM23","PCM33","PCM34","PCM35","PCM36"} ...

 

Regards,

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany
TomMartens
Super User
Super User

Hey @Georgia_H ,

 

maybe these two measures provide what you are looking for:

denominator (basically a distinctcount of the metrics_id column, with ALL (the table) )

 

denominator = 
CALCULATE(
    DISTINCTCOUNT( 'Table'[Metrics_ID] )
    , ALL( 'Table' )
)

 

And the division ( this one is more complex as I'm using the table iterator function AVERAGEX to calculate the average after the division)

 

division = 
    AVERAGEX(
        'Table'
        , DIVIDE( 'Table'[Avg Compliance %]  , [denominator] )
    ) * 100

 

This allows to create a table visual like the one below:
image.png
Regards,

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

HI @TomMartens 

 

Thanks for the quick response. The issue is for those with multiple rows like PAMC in my data set, if you select on PAMC, it will still show as 1 on each row, instead of 12 on every row. That is the issue i am facing. Also, i have a filter on certain metrics_ID for my denominator. 

 

My expected result should be:

Expected Results for PAMC  
LBUMetrics_IDAvg Compliance %Denominator (unique by Metrics_ID)Expected Compliance_Value (AVG) divided by MAX Count of Denominator i.e. 12
PAMCPCM0178.80%126.57%
PAMCPCM0381.30%126.78%
PAMCPCM0462.10%125.18%
PAMCPCM0956.80%124.73%
PAMCPCM1059.60%124.97%
PAMCPCM1968.60%125.72%
PAMCPCM2055.90%124.66%
PAMCPCM2385.90%127.16%
PAMCPCM3365.00%125.42%
PAMCPCM3447.80%123.98%
PAMCPCM3557.10%124.76%
PAMCPCM3662.00%125.17%

Hey @Georgia_H ,

this is how my data looks:
image.png
Here you will find my pbix https://tommartens-my.sharepoint.com/:u:/g/personal/tom_minceddata_com/EUMsIS3jsJBAt6dpaI5hngsB9wwHO...

Regards,

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

Hi Tom,

I tested the concept in my real dataset.

My real dataset has more than 12 Metrics_ID, however i only need to count on 12 Metrics_ID, hence my measure is written like:

ALCULATE(DISTINCTCOUNT('rep F_ITS_MetricsLanding'[Metrics_ID]),FILTER('rep F_ITS_MetricsLanding','rep F_ITS_MetricsLanding'[Metrics_ID] in {"PCM01","PCM03","PCM04","PCM09","PCM10","PCM19","PCM20","PCM23","PCM33","PCM34","PCM35","PCM36"}),ALL('rep F_ITS_MetricsLanding'[Metrics_ID]))

 

I dont get the same results as yours (12 on every row). I still get 1 on the relevant rows. What could be wrong with my DAX syntax?

 

Georgia_H_0-1660378660141.png

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.