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

Join 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.

Reply
Anonymous
Not applicable

Convert SQL to DAX : Subquery

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.

1 ACCEPTED SOLUTION

Hi @Anonymous ,

 

I create the following sample data.

 

vkkfmsft_0-1643009007909.png      vkkfmsft_1-1643009070439.png

 

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 )
                            )
                        )
    )
)

vkkfmsft_2-1643009150262.png

 

 

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.

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Hi @v-kkf-msft 

 

Thanks very much , This approach worked for me. 

DataInsights
Super User
Super User

@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 )
)

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Anonymous
Not applicable

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.

 

vkkfmsft_0-1643009007909.png      vkkfmsft_1-1643009070439.png

 

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 )
                            )
                        )
    )
)

vkkfmsft_2-1643009150262.png

 

 

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.

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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