The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi, I have a dataset of employees working on month-to-month basis,
The dataset looks something like this,
Date | Emp Code | Name | Grade | Field | Allocation |
Aug-22 | 1 | Umair | 1 | ML | 0 |
1-Sep | 1 | Umair | 1 | ML | 0 |
Oct-22 | 1 | Umair | 1 | ML | 0.75 |
Nov-22 | 1 | Umair | 1 | ML | 1 |
Dec-22 | 1 | Umair | 1 | ML | 1 |
Aug-22 | 2 | Avery | 2 | Data Analysis | 1 |
1-Sep | 2 | Avery | 2 | Data Analysis | 0 |
Oct-22 | 2 | Avery | 2 | Data Analysis | 0 |
Nov-22 | 2 | Avery | 2 | Data Analysis | 0 |
Dec-22 | 2 | Avery | 2 | Data Analysis | 0 |
Aug-22 | 3 | Aryub | 2 | Web Dev | 0.9 |
1-Sep | 3 | Aryub | 2 | Web Dev | 1 |
Oct-22 | 3 | Aryub | 2 | Web Dev | 0.9 |
Nov-22 | 3 | Aryub | 2 | Web Dev | 0.75 |
Dec-22 | 3 | Aryub | 2 | Web Dev | 1 |
Aug-22 | 4 | Failak | 3 | ML | 0 |
1-Sep | 4 | Failak | 3 | ML | 0 |
Oct-22 | 4 | Failak | 3 | ML | 0.75 |
Nov-22 | 4 | Failak | 3 | ML | 1 |
Dec-22 | 4 | Failak | 3 | ML | 0.5 |
I have a Slicer for Date Range from which the user can select any date range and data will be filtered accordingly.
I have a Matrix Visual that shows allocation of employees month-wise. There is an additional Filter is applied on this Matrix visual, that it only shows those employees which have been allocated (have allocation > 0) on all months being filtered. For example, If I am filtering from August to December, then only the records which have allocation greater than 0 FOR ALL THE MONTHS (August to December) will be shown. I have also attached two examples below to demonstrate this,
(As only the employee with Emp ID = 3 was allocated on all the months from August to Ddecember, so his record is shown only)
(3 Employees were allocated in both the months of Nov and December, so their records are shown)
This is the measure that I am using currently in this Matrix Visual to filter out the employees which don't have allocation > 0 for all the months being filtered,
Employee Allocated All Months Boolean =
Var _count =
CALCULATE(
DISTINCTCOUNT('Calendar'[Month]),
FILTER(
ALLSELECTED(Competency),
Competency[Emp Code] = MAX(Competency[Emp Code])
)
)
Var _total =
CALCULATE(
DISTINCTCOUNT('Calendar'[Month]),
ALLSELECTED(Competency)
)
RETURN
IF(_count = _total, 1)
My problem comes in the other visuals. I have a visual that shows Total Unique Resources in the Data (As can be seen in the images above). I want this Visual to also act similarly (that is, if the employee is not allocated in all the months being filtered, then he shouldn't be considered in this count. So, if I am filtering from August to December, so this visual should show 1 employee only. And if I am filtering from November to December, so it should show 3 Employees)
Same for the field-wise breakdown of the employees count, only those employees should be counted which are allocated in that specific date range.
MY ATTEMPT:
I tried to achieve this by changing my Total Resources Measure with the following DAX, however it doesn't seem to be giving correct results,
Total Unique Resources - Test =
CALCULATE(
DISTINCTCOUNT(Competency[Emp Code]),
FILTER(
Competency,
[Employee Allocated All Months Boolean] = 1
)
)
Results that I got with this DAX are as follows (it gives correct result for the Total Unique Resources/Employees) but doesn't give correct results in the Grade-wise Breakdown of the Resources (where technically it should show only one employee)
Can anyone help me out in this?
You can also download the complete Power BI File: https://drive.google.com/file/d/1pHapxFQ9MafSwt3yrqN3x5oKocv4pFcv/view?usp=sharing
Solved! Go to Solution.
@HassanAshas First off, applause for an absolute textbook way to post a question on the forums. Bravo! PBIX is attached below signature:
Total Unique Resources - Test 2 =
VAR __AllocatedEmp =
SELECTCOLUMNS(
FILTER(
ADDCOLUMNS(
DISTINCT('Competency'[Emp Code]),
"__AllAllocated",[Employee Allocated All Months Boolean]
),
[__AllAllocated] = 1
),
"__EmpCode",[Emp Code]
)
VAR __Table = INTERSECT(DISTINCT('Competency'[Emp Code]), __AllocatedEmp)
VAR __Result = COUNTROWS(__Table)
RETURN
__Result
@HassanAshas First off, applause for an absolute textbook way to post a question on the forums. Bravo! PBIX is attached below signature:
Total Unique Resources - Test 2 =
VAR __AllocatedEmp =
SELECTCOLUMNS(
FILTER(
ADDCOLUMNS(
DISTINCT('Competency'[Emp Code]),
"__AllAllocated",[Employee Allocated All Months Boolean]
),
[__AllAllocated] = 1
),
"__EmpCode",[Emp Code]
)
VAR __Table = INTERSECT(DISTINCT('Competency'[Emp Code]), __AllocatedEmp)
VAR __Result = COUNTROWS(__Table)
RETURN
__Result
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
18 | |
18 | |
17 | |
15 | |
13 |
User | Count |
---|---|
36 | |
34 | |
19 | |
18 | |
15 |