Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi,
I need help with creating a function.
This is my sample data:
| session_start | session_user | Daily_sum |
| 9/20/2023 | Person 1 | 4 |
| 9/22/2023 | Person 1 | 5 |
| 9/25/2023 | Person 1 | 8 |
| 9/23/2023 | Person 2 | 3 |
| 9/25/2023 | Person 2 | 5 |
| 9/26/2023 | Person 2 | 4 |
| 9/27/2023 | Person 2 | 7 |
I need to find out the session_start date when the sum of each of the session_user goes below 10, calculated backwards from today.
In the sample data calculated from today (9/28/2023) backwards for Person 1 the date when the sum of Daily_sum values goes below 10 is 9/23/2023 (because 9/22/2023 adds 5) and Person 2's 9/27/2023 (because 9/26/2023 adds 4). I also need to be able to set how many days into the past the data is calculated.
I figured that I need to make the following two steps multiple times. First select the data that are in the past n days: (here 10 days) Table.SelectRows(Source, each Date.IsInPreviousNDays([session_start], 10)).
Then group those by "session_user":
Table.Group(Custom, {"session_user"}, {{"Sum", each List.Sum([Daily_sum]), type nullable number}}).
Then I need to select the rows from the data that are in the past n - 1 days. Then group those by "session_user" and so on until today.
I was able to create a custom function that finds the value how many loops it takes for any of the values for session_users is below 10.
Here is the function:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WKk4tLs7Mz4svLkksKlHSgfNLi1OLgFyXxMycyvji0lylWJ1oJUt9IwMgMjIGygSkFhXn5ykYApkmMEkjLJKmMElTLJIWMEljNEkjINMYl04jZGPNsEjCHWSORdJcKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t]),
#"Promoted headers" = Table.PromoteHeaders(Source, [PromoteAllScalars = true]),
#"Changed column type" = Table.TransformColumnTypes(#"Promoted headers", {{"session_start", type date}, {"session_user", type text}, {"Daily_sum", Int64.Type}}),
CustomFunction = (n as number) as table =>
let
FilteredRows = Table.SelectRows(#"Changed column type", each Date.IsInPreviousNDays([session_start], n)),
GroupedRows = Table.Group(FilteredRows, {"session_user"}, {{"Sum", each List.Sum([Daily_sum]), type nullable number}}),
Result = if List.Min(GroupedRows[Sum]) < 10 then Table.AddColumn(GroupedRows, "Final N Value", each n) else @CustomFunction(n-1)
in
Result,
FinalResult =
CustomFunction(10)
in
FinalResult
Here is the result at the moment:
The function has stopped because Person 1's sum is less than 10 but at the same time I need to find out when Person 2's sum goes below 10.
How can I achieve this?
Solved! Go to Solution.
Hi @Anonymous ,
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WstQ3MgAiI2MlHaWA1KLi/DwFQyDTRClWByxphEXSFCZpikXSAiZpjCZpBGQa49JphGysGRZJuIPMsUiaK8XGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [session_start = _t, session_user = _t, Daily_sum = _t]),
#"Changed column type" = Table.TransformColumnTypes(Source, {{"session_start", type date}, {"session_user", type text}, {"Daily_sum", Int64.Type}}),
CustomFunction = (user as text, n as number) as table =>
let
FilteredRows = Table.SelectRows(#"Changed column type", each [session_user] = user and Date.IsInPreviousNDays([session_start], n)),
GroupedRows = Table.Group(FilteredRows, {"session_user"}, {{"Sum", each List.Sum([Daily_sum]), type nullable number}}),
Result = if List.Min(GroupedRows[Sum]) < 10 then Table.AddColumn(GroupedRows, "Final N Value", each n) else @CustomFunction(user, n-1)
in
Result,
Users = List.Distinct(#"Changed column type"[session_user]),
Results = List.Transform(Users, each CustomFunction(_, 10)),
FinalResult = Table.Combine(Results)
in
FinalResult
Output:
If I've misunderstood your question, feel free to contact me.
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Hi @Anonymous ,
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WstQ3MgAiI2MlHaWA1KLi/DwFQyDTRClWByxphEXSFCZpikXSAiZpjCZpBGQa49JphGysGRZJuIPMsUiaK8XGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [session_start = _t, session_user = _t, Daily_sum = _t]),
#"Changed column type" = Table.TransformColumnTypes(Source, {{"session_start", type date}, {"session_user", type text}, {"Daily_sum", Int64.Type}}),
CustomFunction = (user as text, n as number) as table =>
let
FilteredRows = Table.SelectRows(#"Changed column type", each [session_user] = user and Date.IsInPreviousNDays([session_start], n)),
GroupedRows = Table.Group(FilteredRows, {"session_user"}, {{"Sum", each List.Sum([Daily_sum]), type nullable number}}),
Result = if List.Min(GroupedRows[Sum]) < 10 then Table.AddColumn(GroupedRows, "Final N Value", each n) else @CustomFunction(user, n-1)
in
Result,
Users = List.Distinct(#"Changed column type"[session_user]),
Results = List.Transform(Users, each CustomFunction(_, 10)),
FinalResult = Table.Combine(Results)
in
FinalResult
Output:
If I've misunderstood your question, feel free to contact me.
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!