Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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?
Solved! Go to Solution.
Hi @kamgib ,
Here I create a sample to have a test.
A:
B:
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.
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.
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.
Hi @kamgib ,
Here I create a sample to have a test.
A:
B:
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.
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.
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
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
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
25 | |
19 | |
18 | |
18 | |
18 |
User | Count |
---|---|
37 | |
25 | |
18 | |
17 | |
13 |