Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Dear all,
I have the following issue which I think should be relatively easy to solve, but I have not found a solution yet. Currently I have below table in excel but I would like to get the same result (Column F) in a query in PowerBI. Basically it comes down to this, Column A is a long list of events happening on the specified date/time. I would like to count how many events happen (F) in a timeframe of 10 minutes (between C and D). Some helper columns are made to come to the result in column F (Column B en E)
In Excel the following calculations are applied, but perhaps the calcaluation could be made way easier in PowerBI. Hope somebody could help me out with this one! If more info is needed please let me know.
A = raw data
B = VLOOKUP(A2;C$2:E$8527;3)
C = A
D = A + 10 minutes
E = Index column
F= COUNTIF(B:B;E2)
Column A | ColumnB | ColumnC | ColumnD | ColumnE | ColumnF |
Timestamp | Count | Timestart | Time + 10 minutes | Index | Slice count |
1-09-20 0:00:04 | 1 | 1:9:2020 00:00:04 | 1:9:2020 00:10:04 | 1 | 1 |
1-09-20 0:02:48 | 2 | 1:9:2020 00:02:48 | 1:9:2020 00:12:48 | 2 | 1 |
1-09-20 0:14:07 | 3 | 1:9:2020 00:14:07 | 1:9:2020 00:24:07 | 3 | 1 |
1-09-20 0:24:49 | 4 | 1:9:2020 00:24:07 | 1:9:2020 00:34:07 | 4 | 3 |
1-09-20 0:27:04 | 4 | 1:9:2020 00:34:07 | 1:9:2020 00:44:07 | 5 | 1 |
1-09-20 0:31:37 | 4 | 1:9:2020 00:44:07 | 1:9:2020 00:54:07 | 6 | 0 |
1-09-20 0:35:04 | 5 | 1:9:2020 00:54:07 | 1:9:2020 01:04:07 | 7 | 0 |
1-09-20 1:15:35 | 9 | 1:9:2020 01:04:07 | 1:9:2020 01:14:07 | 8 | 0 |
1-09-20 1:19:23 | 9 | 1:9:2020 01:14:07 | 1:9:2020 01:24:07 | 9 | 2 |
1-09-20 1:24:08 | 10 | 1:9:2020 01:24:07 | 1:9:2020 01:34:07 | 10 | 3 |
1-09-20 1:25:45 | 10 | 1:9:2020 01:34:07 | 1:9:2020 01:44:07 | 11 | 1 |
1-09-20 1:33:30 | 10 | 1:9:2020 01:44:07 | 1:9:2020 01:54:07 | 12 | 1 |
Solved! Go to Solution.
Hi @Anonymous ,
You can modify the formula like this:
Column =
VAR __Start = [Timestart]
VAR __End = [Time + 10 Minutes]
VAR _count =
COUNTROWS (
FILTER ( ALL ( 'table' ), [Timestamp] >= __Start && [Timestamp] <= __End )
)
RETURN
IF ( ISBLANK ( _count ), 0, _count )
Best Regards,
Yingjie Li
If this post helps then please consider Accept it as the solution to help the other members find it more quickly.
@Anonymous - Should be something like:
Column =
VAR __Start = [Timestart]
VAR __End = [Time + 10 Minutes]
RETURN
COUNTROWS([Timestamp]>=__Start && [Timestamp]<=__End)
Dear @Greg_Deckler
Thanks for your quick reply! Your solution translates as following in my powerBI file:
Hi @Anonymous ,
You can modify the formula like this:
Column =
VAR __Start = [Timestart]
VAR __End = [Time + 10 Minutes]
VAR _count =
COUNTROWS (
FILTER ( ALL ( 'table' ), [Timestamp] >= __Start && [Timestamp] <= __End )
)
RETURN
IF ( ISBLANK ( _count ), 0, _count )
Best Regards,
Yingjie Li
If this post helps then please consider Accept it as the solution to help the other members find it more quickly.
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
64 | |
61 | |
23 | |
17 | |
12 |