Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hi All, I am trying to convert the following SQL Code to DAX but i am stuck with implementation of the subquery part.
I am trying to get the Distinct patient count in the selected range also have the appointment booked in the future.
Current Date Range is Dec 1st 2021 to Dec 31st 2021
select count(distinct patient_id)
from fact_appointment
where appointment_date > '2021-12-31'
and patient_id in
(
select distinct patient_id
from fact_appointment_detail
where appointment_date between '2021-12-01' and '2021-12-31'
)
Any help will good.
Solved! Go to Solution.
Hi @Anonymous ,
I create the following sample data.
Then create the measure:
CountID =
CALCULATE (
DISTINCTCOUNT ( fact_appointment[patient_id] ),
FILTER (
fact_appointment,
fact_appointment[appointment_date] > DATE ( 2021, 12, 31 )
&& fact_appointment[product_ID]
IN { "A123", "B234", "C345" }
&& fact_appointment[patient_id]
IN CALCULATETABLE (
VALUES ( fact_appointment_detail[patient_id] ),
FILTER (
fact_appointment_detail,
fact_appointment_detail[product_ID]
IN { "A123", "B234", "C345" }
&& fact_appointment_detail[appointment_date] >= DATE ( 2021, 12, 1 )
&& fact_appointment_detail[appointment_date] <= DATE ( 2021, 12, 31 )
)
)
)
)
If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@Anonymous,
Try this measure:
Patient Count =
CALCULATE (
DISTINCTCOUNT ( fact_appointment[patient_id] ),
fact_appointment[appointment_date] > DATE ( 2021, 12, 31 ),
fact_appointment_detail[appointment_date] >= DATE ( 2021, 12, 1 ),
fact_appointment_detail[appointment_date] <= DATE ( 2021, 12, 31 )
)
Proud to be a Super User!
This measure is returning blank , its not working
Plus i am trying to add another filter in the DAX
SQL:
select count(distinct patient_id)
from fact_appointment
where appointment_date > '2021-12-31' and product_ID in {'A123','B234','C345'}
and patient_id in
(
select distinct patient_id
from fact_appointment_detail
where appointment_date between '2021-12-01' and '2021-12-31' and
product_ID in {'A123','B234','C345'}
)
DAX tried for this logic :
CALCULATE(DISTINCTCOUNT(fact_appointment[patient_id]),
Filter(ALL(fact_appointment),(
fact_appointment[appointment_date] > MAX(fact_appointment[appointment_date]) && (
fact_appointment[procedure_code] in {"A","C","D"}))),
fact_appointment[office_patient_id] in
(DISTINCT(fact_appointment[office_patient_id])))
but it should add filter condition of product id in the "IN" statement, i am unable to get it .
dax should be like
CALCULATE(DISTINCTCOUNT(fact_appointment[patient_id]),
Filter(ALL(fact_appointment),(
fact_appointment[appointment_date] > MAX(fact_appointment[appointment_date]) && (
fact_appointment[product_ID] in {"A123","C234","D345"}))),
fact_appointment[office_patient_id] in
(DISTINCT(fact_appointment[office_patient_id]),
fact_appointment[product_ID] in {"A123","C234","D345"}))
Hi @Anonymous ,
I create the following sample data.
Then create the measure:
CountID =
CALCULATE (
DISTINCTCOUNT ( fact_appointment[patient_id] ),
FILTER (
fact_appointment,
fact_appointment[appointment_date] > DATE ( 2021, 12, 31 )
&& fact_appointment[product_ID]
IN { "A123", "B234", "C345" }
&& fact_appointment[patient_id]
IN CALCULATETABLE (
VALUES ( fact_appointment_detail[patient_id] ),
FILTER (
fact_appointment_detail,
fact_appointment_detail[product_ID]
IN { "A123", "B234", "C345" }
&& fact_appointment_detail[appointment_date] >= DATE ( 2021, 12, 1 )
&& fact_appointment_detail[appointment_date] <= DATE ( 2021, 12, 31 )
)
)
)
)
If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
65 | |
63 | |
52 | |
37 | |
36 |
User | Count |
---|---|
82 | |
67 | |
61 | |
46 | |
45 |