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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
chrisgill
Frequent Visitor

Distinct Count using multiple row context filters

I'm trying to create a calculated column in a table that returns the count of all rows in a table that match multiple criteria from the current row. Something like this:

 

ContractTypeTermcodePersonIDEnrollmentCountInTerm (desired result, calculated column)
20A103
21A113
20B122
20A241
20A163
21B132
20B221
22A123

 

IThe formula needs to count the number of distinct contract types for each row that match the values for that row. 'm trying to create statement logic that matches this pseudo-code:

CountInTerm = Count distinct ContractType where TermCode = ThisRow(TermCode) and PersonID = ThisRow(PersonID) and Enrollment > 0. 

 

I've tried a variety of approaches including:

 

CALCULATE(DISTINCTCOUNT(ContractType), TermCode=EARLIER(TermCode) && PersonID = EARLIER(PersonID)) but this returns an error that I can't nest Earlier functions.

 

I also tried creating a calculated table and returning Countrows, but the value for all rows is always 1. 

var TC = TermCode var PID = PersonID var TestCount = CALCULATETABLE(DISTINCT(ContractTypeKey), TermCode = TC, PersonID = PID) return COUNTROWS(TestCount)

 

If I simplify for troubleshooting and use CountInTerm = DISTINCT(ContractType) I get the correct count of total distinct contract types in the table (9 for all rows in my full table). If I use CountInTerm = CALCULATE(DISTINCTCOUNT(ContractType)) the value becomes 1 for every row. I'm assuming this is because a row context is being applied.

 

Is there a way to add row context values to a calculation that then performs the calculation over an entire column?

1 ACCEPTED SOLUTION
Greg_Deckler
Community Champion
Community Champion

@chrisgill Try:

Column = 
    VAR __Termcode = [Termcode]
    VAR __PersonID = [PersonID]
RETURN
    COUNTROWS(DISTINCT(SELECTCOLUMNS(FILTER('Table6',[Termcode] = __Termcode && [PersonID] = __PersonID),"ContractType",[ContractType])))


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

2 REPLIES 2
Greg_Deckler
Community Champion
Community Champion

@chrisgill Try:

Column = 
    VAR __Termcode = [Termcode]
    VAR __PersonID = [PersonID]
RETURN
    COUNTROWS(DISTINCT(SELECTCOLUMNS(FILTER('Table6',[Termcode] = __Termcode && [PersonID] = __PersonID),"ContractType",[ContractType])))


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

@Greg All worked exactly as hoped. Thank you very much for the help!

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

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

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.