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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
kamgib
Frequent Visitor

SQL to DAX

Two tables, Table A has User/Event/EventDate. Table B has User/InteractionDate.

 

I would use the following SQL Statement to get a one to many table; 

     Select A.User, A.Event, A.EventDate, B.User, B.InteractionDate
      From A, B
      where A.User = B.User
             AND
                (
                  B.InteractionDate >= A.EventDate
                         AND
                  B.InteractionDate <= DateAdd(A.EventDate,30)
                 )

the A.User = B.User is related and can be in a JOIN instead of in the WHERE Clause.

any help to convert this to a DAX or PowerQuery process and get the same results?

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

Hi @kamgib ,

 

Here I create a sample to have a test.

A:

RicoZhou_0-1658480152845.png

B:

RicoZhou_1-1658480159419.png

By Power Query:

let
    Source = Table.NestedJoin(A, {"User"}, B, {"User"}, "B", JoinKind.LeftOuter),
    #"Expanded B" = Table.ExpandTableColumn(Source, "B", {"User", "InteractionDate"}, {"B.User", "B.InteractionDate"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded B", each [B.InteractionDate] >= [EventDate] and [B.InteractionDate]<=Date.AddDays([EventDate],30))
in
    #"Filtered Rows"

 Result is as below.

RicoZhou_2-1658480181576.png

 

By Dax:

Dax Table = 
VAR _ADD = ADDCOLUMNS(A,"B.User",RELATED(B[User]),"B.InteractionDate",RELATED(B[InteractionDate]))
VAR _FILTER = FILTER(_ADD,[B.InteractionDate]>=[EventDate]&&[B.InteractionDate]<=[EventDate]+30)
RETURN
_FILTER

Result is as below.

RicoZhou_3-1658480466139.png

 

Best Regards,
Rico Zhou

 

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
v-rzhou-msft
Community Support
Community Support

Hi @kamgib ,

 

Here I create a sample to have a test.

A:

RicoZhou_0-1658480152845.png

B:

RicoZhou_1-1658480159419.png

By Power Query:

let
    Source = Table.NestedJoin(A, {"User"}, B, {"User"}, "B", JoinKind.LeftOuter),
    #"Expanded B" = Table.ExpandTableColumn(Source, "B", {"User", "InteractionDate"}, {"B.User", "B.InteractionDate"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded B", each [B.InteractionDate] >= [EventDate] and [B.InteractionDate]<=Date.AddDays([EventDate],30))
in
    #"Filtered Rows"

 Result is as below.

RicoZhou_2-1658480181576.png

 

By Dax:

Dax Table = 
VAR _ADD = ADDCOLUMNS(A,"B.User",RELATED(B[User]),"B.InteractionDate",RELATED(B[InteractionDate]))
VAR _FILTER = FILTER(_ADD,[B.InteractionDate]>=[EventDate]&&[B.InteractionDate]<=[EventDate]+30)
RETURN
_FILTER

Result is as below.

RicoZhou_3-1658480466139.png

 

Best Regards,
Rico Zhou

 

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

 

thanks for posting, I will give it a try and report back.

Hi @kamgib ,

 

Could you tell me if your issue has been solved? If it is, kindly Accept the helpful reply as the solution. More people will benefit from it. Or you are still confused about it, please provide me with more details about your data model and your issue or share me with your pbix file without sensitive data.


Best Regards,

Rico Zhou

PAG
Frequent Visitor

Hi,

 

I think you can in PowerQuery merge the two tables

then create a column that adds 30 days to the Eventdate column, call it Eventdate30 for example

Next create a column that subtract the column InteractionDate by Eventdate30 and another that subtract InteractionDate by Eventdate.

Now you can filter the merged table by the last two columns you've created like you want

 

Hope it helps

PAG

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors