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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
deedeedudu
Helper II
Helper II

Distinct count across two tables based on matching id, status and date condition

Hi ,

I need help with the following attached file.

I want to calculate conversion for each route_id for the two calendar years of 2021 and 2022 based on following condition:

1. The contact_id should be matching in the two tables activity and payment

2. The payment date should be after activity datetime and should be within 15 days of the activity datetime

3. activity[status] should be "read"

4. There are multiple "read" for each route_id and only the newest datetime of "read" should be considered

 

I've created a measure as following

ConversionCount = 
VAR _journey = CALCULATETABLE(VALUES(activity[contact_id]),activity[status] = "read")
VAR _education = VALUES(payment[contact_id])
RETURN
IF(MAX(activity[datetime]) <= MAX(payment[date]) && (MAX(activity[datetime]) +15) >= MAX(payment[date]),COUNTROWS(DISTINCT(INTERSECT(_education,_journey))))

 

 

But it is not giving the output correctly as seen in the page titled Cross_check where the count is shown as 669 of total conversion but if i export the table and do a manual row count it comes to 618 and there are duplicate contact_ids as well which shouldn't be counted. If i only do a manual count of distinct contact_id in the exported table it comes to 417

 

I want the final output as mentioned in the page Desired output.

Sample data 

1 ACCEPTED SOLUTION
v-chenwuz-msft
Community Support
Community Support

Hi @deedeedudu ,

 

Maybe you can try this code:

Measured =
VAR _1 =
    SUMMARIZE (
        FILTER ( 'activity', [status] = "read" ),
        [contact_id],
        "newest", MAX ( 'activity'[datetime] ),
        "pt", MAX ( 'payment'[date] )
    )
VAR _2 =
    FILTER (
        ADDCOLUMNS (
            _1,
            "if in",
                IF ( [newest] <= [pt] && [pt] <= [newest] + 15, 1, 0 )
        ),
        [if in] = 1
    )
RETURN
COUNTROWS(_2)

 

 

Pbix in the end you can refer.

Best Regards

Community Support Team _ chenwu zhu

 

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

3 REPLIES 3
v-chenwuz-msft
Community Support
Community Support

Hi @deedeedudu ,

 

Maybe you can try this code:

Measured =
VAR _1 =
    SUMMARIZE (
        FILTER ( 'activity', [status] = "read" ),
        [contact_id],
        "newest", MAX ( 'activity'[datetime] ),
        "pt", MAX ( 'payment'[date] )
    )
VAR _2 =
    FILTER (
        ADDCOLUMNS (
            _1,
            "if in",
                IF ( [newest] <= [pt] && [pt] <= [newest] + 15, 1, 0 )
        ),
        [if in] = 1
    )
RETURN
COUNTROWS(_2)

 

 

Pbix in the end you can refer.

Best Regards

Community Support Team _ chenwu zhu

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

deedeedudu
Helper II
Helper II

Hi,

Can someone please help? 

deedeedudu
Helper II
Helper II

To all the experts, please help.

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

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