Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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:
ContractType | Termcode | PersonID | Enrollment | CountInTerm (desired result, calculated column) |
20 | A | 1 | 0 | 3 |
21 | A | 1 | 1 | 3 |
20 | B | 1 | 2 | 2 |
20 | A | 2 | 4 | 1 |
20 | A | 1 | 6 | 3 |
21 | B | 1 | 3 | 2 |
20 | B | 2 | 2 | 1 |
22 | A | 1 | 2 | 3 |
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?
Solved! Go to Solution.
@chrisgill Try:
Column =
VAR __Termcode = [Termcode]
VAR __PersonID = [PersonID]
RETURN
COUNTROWS(DISTINCT(SELECTCOLUMNS(FILTER('Table6',[Termcode] = __Termcode && [PersonID] = __PersonID),"ContractType",[ContractType])))
@chrisgill Try:
Column =
VAR __Termcode = [Termcode]
VAR __PersonID = [PersonID]
RETURN
COUNTROWS(DISTINCT(SELECTCOLUMNS(FILTER('Table6',[Termcode] = __Termcode && [PersonID] = __PersonID),"ContractType",[ContractType])))
User | Count |
---|---|
22 | |
11 | |
8 | |
6 | |
6 |
User | Count |
---|---|
25 | |
13 | |
11 | |
9 | |
6 |