Forum

Distinct Count or C...
 
Notifications
Clear all

Distinct Count or Count Rows - Measured Counts

4 Posts
2 Users
0 Reactions
219 Views
(@jumpmanz5)
Posts: 17
Eminent Member
Topic starter
 

I'm so new to Power Pivot I might be dangerous. 🙂 Meaning my grasps of formula creation (measured or otherwise is limited).   

I work in a procurement organization and we track the metrics related to our suppliers, which is information pulled from multiple systems and compiled into a single excel file.  From this reports are generated (nothing automated), but I and trying to add a level of automation to this process.   I've done a decent job in automating the count of suppliers and subcontract agreements across multiple division, program, and suppliers, but have a difficult time determining a the correct measure formula need to produce the count I actually need (last piece of the puzzle).   

Initially, I started with using DISTINCTCOUNT applied to a supplier ID, which does give me the exact count of suppliers within a division, but I need to the count to reflect the total suppliers within a division based on how many programs they are working on.   Ex:  if they work on Program A and B, I need my count to be 2 not 1, which is what DISTINTCOUNT programs.   

 

Below is a sample of data, if I use DISTINCTCOUNT I have a total of 7 suppliers, but I actually need to have the count of 10 based on the program within the division.   Any help would be greatly appreciated it.  

 

The measure DAF formula I currently have is =DISTINCTCOUNT(SupplierData[Supplier ID])

Any help would be greatly appreciated.  

 

Program Name PO Number Order Type PO Type Supplier ID Supplier Companies Per Program 
Program A P000092086 Labor Hour (LH) Subcontract S0000068316 Company A 2
Program A P000086431 Labor Hour (LH) Subcontract S0000068316 Company A
Program A P000095134 Labor Hour (LH) Subcontract S0000003820 Company B
Program B P000091844 Labor Hour (LH) Subcontract S0000009654 Company C 2
Program B P000086420 Labor Hour (LH) Subcontract S0000009654 Company C
Program B P000086135 Labor Hour (LH) Subcontract S0000005070 Company D
Program B P000089249 Labor Hour Letter Subcontract S0000004571 Company D
Program C  P000074931 Labor Hour Subcontract S0000058388 Company D 6
Program C  P000054402 Time and Materials (TM) Subcontract S0000015135 Company A
Program C  P000089915 Labor Hour Subcontract S0000054516 Company B
Program C  P000086171 Labor Hour (LH) Subcontract S0000007907 Company E
Program C  P000085837 Labor Hour (LH) Subcontract S0000067205 Company F
Program C  P000086336 Labor Hour (LH) Subcontract S0000056315 Company G
 
Posted : 04/06/2021 2:55 pm
(@mynda)
Posts: 4762
Member Admin
 

Hi Sid,

You can use this formula:

= SUMX (

VALUES ( Table2[Program Name] ),

CALCULATE ( DISTINCTCOUNT ( Table2[Supplier] ) )

)

See attached.

Mynda

 
Posted : 05/06/2021 3:36 am
(@jumpmanz5)
Posts: 17
Eminent Member
Topic starter
 

Mynda,

Works perfectly.  Thank you! 

If I may ask a follow on question.   I am looking to use my pivot table as part of my dashboard and right now I have a filter that a column-based True / False.   However, it adds the filter above my pivot table, which I don't want to have on the dashboard, I would just prefer it not be there. 

So I'm thinking it would be easier to just add the filter to the formula you provided, but can't seem to figure out its placement within the formula.  Do you need to filter first then do the sumx and distinctcount?  Or would sum and calculate first then filter out all the "False" rows leaving the count of "True" only.   Thanks

  

= SUMX (

VALUES ( Table2[Program Name] ),

CALCULATE ( DISTINCTCOUNT ( Table2[Supplier] ) )

)
 
Posted : 09/06/2021 9:38 am
(@mynda)
Posts: 4762
Member Admin
 

Hi Sid,

Did you try this:


=SUMX (

VALUES ( Table2[Program Name] ),

CALCULATE ( DISTINCTCOUNT ( Table2[Supplier] ), Table2[Status]=TRUE )

)

i.e. where the column containing the TRUE/FALSE values is called Status.

Mynda

 
Posted : 10/06/2021 7:27 am
Share: