March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi,
I'm trying to count the number of resources that are assigned to a Project.
A simple distinct count wouldn't work because there are instances where a resource is assigned in the same period but on a different Project.
Say I have:
Resource ProjectNr Desired Result
Tool1 01 1
Tool1 01 0
Tool2 02 1
Tool3 03 1
Tool1 04 1
The desired result would be 4.
This needs to be a DAX formula and it needs to be a column that I can reference in a table.
The way I'd solve this in excel would be to create an "ID" out of the combination of Resource+ProjectNr Column and then only count the first occurrence:
A B =COUNTIF($A$1:$A1,$A1)=1)+0
Tool101 1
Tool101 0
Tool202 1
Tool303 1
Tool104 1
Solved! Go to Solution.
Hi @WorkHard ,
Try this:
1. Add an Index column in Power Query Editor.
2. Create a column.
First Instance =
IF (
COUNTROWS (
FILTER (
'Table',
'Table'[Resource] = EARLIER ( 'Table'[Resource] )
&& 'Table'[ProjectNr] = EARLIER ( 'Table'[ProjectNr] )
&& 'Table'[Index] <= EARLIER ( 'Table'[Index] )
)
) = 1,
1,
0
)
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @WorkHard ,
Try this:
1. Add an Index column in Power Query Editor.
2. Create a column.
First Instance =
IF (
COUNTROWS (
FILTER (
'Table',
'Table'[Resource] = EARLIER ( 'Table'[Resource] )
&& 'Table'[ProjectNr] = EARLIER ( 'Table'[ProjectNr] )
&& 'Table'[Index] <= EARLIER ( 'Table'[Index] )
)
) = 1,
1,
0
)
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks Icey,
This would work except I'm stuck down a rabbit hole trying to create an index column. I can't just use query editor to add an index column because I'm in Live mode that doesn't have a query.
Unsure how many more helper columns I need to create to get this to work. RANKX will rank the same number in my case which means I need to create another extra column as some sort of ID....
Update:
Thank you both for your help, I ended up using Icey's solution and created an index column using 2 additional columns:
First Column (RND) to create a random number for each row
Second Column (Index) to create an index number based on the random values
RND = RAND()
Index = RANKX('TableName',[RND],[RND],ASC,Dense)
Hi @WorkHard
Did you tried the measure I have post before?
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsMfelix,
Yes but unfortunately a measure wouldn't work in my situation. I'm summarizing a table and I'm creating a UNION with another table (cache old data tabke) vs (live data table) and this numbering needs to be a column, not a measure.
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsRegards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsMarch 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
133 | |
90 | |
88 | |
64 | |
58 |
User | Count |
---|---|
201 | |
137 | |
107 | |
70 | |
68 |