• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Distinct Count or Count Rows - Measured Counts|Power Pivot|Excel Forum|My Online Training Hub

You are here: Home / Distinct Count or Count Rows - Measured Counts|Power Pivot|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower PivotDistinct Count or Count Rows - Meas…
sp_PrintTopic sp_TopicIcon
Distinct Count or Count Rows - Measured Counts
Avatar
Sid Jones
Member
Members
Level 0
Forum Posts: 11
Member Since:
April 15, 2021
sp_UserOfflineSmall Offline
1
June 4, 2021 - 4:55 am
sp_Permalink sp_Print

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
sp_AnswersTopicSeeAnswer See Answer
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4447
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
June 4, 2021 - 5:36 pm
sp_Permalink sp_Print

Hi Sid,

You can use this formula:

= SUMX (

VALUES ( Table2[Program Name] ),

CALCULATE ( DISTINCTCOUNT ( Table2[Supplier] ) )

)

See attached.

Mynda

sp_AnswersTopicAnswer
Answers Post
Avatar
Sid Jones
Member
Members
Level 0
Forum Posts: 11
Member Since:
April 15, 2021
sp_UserOfflineSmall Offline
3
June 8, 2021 - 11:38 pm
sp_Permalink sp_Print sp_EditHistory

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

)
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4447
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
4
June 9, 2021 - 9:27 pm
sp_Permalink sp_Print

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

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Velouria, Lionel Baijot, Jack Brett, Ivica Cvetkovski
Guest(s) 12
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Hayden Hao
Angela chen
Sean Moore
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Forum Stats:
Groups: 3
Forums: 24
Topics: 6211
Posts: 27239

 

Member Stats:
Guest Posters: 49
Members: 31891
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.