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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Spekko
Helper I
Helper I

Filter data based on date-field in other table

After lurking frequently in this community, time for my first post.

 

Is it posible to filter results in a visual based on the contents of another table?
In this case: i've got Marketing Qualified Leads coming in through our website. This has an Entry Date (MQLDate).

 

MQL ID MQLDate

116-09-2020
217-09-2020

then there is another table, with Leads.

 

Lead ID MQL Id Lead Create Date

1114-09-2020
2118-09-2020
3219-09-2020

What I want is that when I select MQL Id 1 in my dashboard, that the dashboard only shows me leads, related to MQL Id 1, where the Lead Create Date is more recent than the MQLdate. So in the example above, It should only show Lead ID 2.

 

Another approach I probably need is not only getting all related information after the MQLDate, but also 'only the first lead after the MQLDate'. Hope my description is clear enough.

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @Spekko ,

 

Try this:

 

1. Create relationship between the two tables.

mql-re.JPG

 

2. Create measures:

  • Show all related information after the MQLDate.
Measure 1 = IF ( MIN ( 'Lead'[Lead Create Date] ) > SELECTEDVALUE ( 'MQL'[MQLDate] ), 1 )
  •  Show only the first lead after the MQLDate.
Measure 2 = 
VAR MinLeadCreateDate =
    CALCULATE (
        MIN ( 'Lead'[Lead Create Date] ),
        FILTER (
            ALLSELECTED ( 'Lead' ),
            'Lead'[MQL Id] = SELECTEDVALUE ( 'MQL'[MQL ID] )
                && 'Lead'[Lead Create Date] > SELECTEDVALUE ( MQL[MQLDate] )
        )
    )
RETURN
    IF (
        SELECTEDVALUE ( MQL[MQL ID] ) = BLANK (),
        1,
        IF ( MIN ( 'Lead'[Lead Create Date] ) = MinLeadCreateDate, 1 )
    )

 

3. Put measures into "Filters on this visual" field of needed visuals and set "is 1", then test.

mql.gif

 

BTW, .pbix file attached.

 

 

Best Regards,

Icey

 

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

5 REPLIES 5
Icey
Community Support
Community Support

Hi @Spekko ,

 

Try this:

 

1. Create relationship between the two tables.

mql-re.JPG

 

2. Create measures:

  • Show all related information after the MQLDate.
Measure 1 = IF ( MIN ( 'Lead'[Lead Create Date] ) > SELECTEDVALUE ( 'MQL'[MQLDate] ), 1 )
  •  Show only the first lead after the MQLDate.
Measure 2 = 
VAR MinLeadCreateDate =
    CALCULATE (
        MIN ( 'Lead'[Lead Create Date] ),
        FILTER (
            ALLSELECTED ( 'Lead' ),
            'Lead'[MQL Id] = SELECTEDVALUE ( 'MQL'[MQL ID] )
                && 'Lead'[Lead Create Date] > SELECTEDVALUE ( MQL[MQLDate] )
        )
    )
RETURN
    IF (
        SELECTEDVALUE ( MQL[MQL ID] ) = BLANK (),
        1,
        IF ( MIN ( 'Lead'[Lead Create Date] ) = MinLeadCreateDate, 1 )
    )

 

3. Put measures into "Filters on this visual" field of needed visuals and set "is 1", then test.

mql.gif

 

BTW, .pbix file attached.

 

 

Best Regards,

Icey

 

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

Wow that really helps! Thanks for the effort you put in!

Anonymous
Not applicable

Use slicer

Thanks for the reply.

 

I don't think I fully understand (yet), I actually do not want to present the end user with a manual action, which, as far as I know, a slicer does give. Can it also be done automatically? So that the metric/visual shows only the relevant data from the first lead linked to the MQL? Like putting in a dynamic field as a filter on the visual, where the content of the dynamic field is the date from the selected MQL?

Yggdrasill
Responsive Resident
Responsive Resident

Go to Model View in Power BI Desktop (left most pane you'll find with 3 icons)

 

Left click and hold the button on ID from table1 and drag it to ID in table 2. Now you have a 1:N (1 to many relationship) between your tables.

 

Go back to Report View and drag ID from table 1 into the canvas. Change the visual to a slicer and you're good to go

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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