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
D-Jeffrey
Frequent Visitor

Rolling total of points and count of IDs on a less than per day basis

Here is a real challenge, that I have been trying to solve for a few years with a more elegant solution -- Rolling total of points and count of IDs on a less than per day basis.

 

StartDateTime

StopDateTime

ID

NumPoints

4/2/2019 2:34

4/2/2019 4:22

20394007

10

4/2/2019 2:44

4/2/2019 4:10

20394008

45

4/2/2019 6:34

4/2/2019 6:59

20394038

2

4/2/2019 6:47

4/2/2019 7:30

20394070

1

4/2/2019 7:10

4/2/2019 7:21

20394071

1

4/2/2019 7:37

4/2/2019 7:42

20394072

1

4/2/2019 7:48

4/2/2019 8:02

20394073

2

4/2/2019 8:20

4/2/2019 8:45

20394074

1

4/2/2019 8:31

4/2/2019 9:16

20394075

1

4/2/2019 8:31

4/2/2019 15:20

20394075

7

 

I would like to get a measure to work against a datetime which shows me at any hour in time (less or more) the total points in a ‘Start’ state.  The Number of start state points occurs at points of time between StartDateTime and StopDateTime and is the rolling sum of the NumPoints.

 

So an hourly table of the above would look like this:

DateTime (bins)

Count of ID

Total of NumPoints Started

4/2/2019 1:00

0

0

4/2/2019 2:00

2

55

4/2/2019 3:00

2

55

4/2/2019 4:00

2

55

4/2/2019 5:00

0

0

4/2/2019 6:00

2

3

4/2/2019 7:00

4

4

4/2/2019 8:00

4

11

4/2/2019 9:00

3

9

4/2/2019 10:00

1

7

4/2/2019 11:00

1

7

 

I would like to have a Measure calculation for ‘Count of ID’ and ‘Total NumPoints Started’

My first bunch of attempted include load the records, breaking the date and time down into date and hour, then created a time timetable.  Creating a link to a Start table and then a link to a Stop Table (both of which duplicated the top table) from the timetable.  Then I did a set of cumulative totals of both tables and subtracted one set of cumulative total from the other.  It is very messy and has issues when you try to apply filtering to the views.  Additionally, when you start to work with 300K of records and filter and graph wit longer periods of time than a day or two, it really starts to grind hard.

 

Any suggestions on how to build a set of measures?

Thank for any help in advance,

DJ

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

Hi @D-Jeffrey ,

 

We can create two measures as below.

countid = 
VAR a =
    MAX ( 'except'[DateTime (bins)] )
RETURN
    CALCULATE (
        COUNT ( 'Table'[ID] ),
        FILTER (
            ALL ( 'Table' ),
            DATE ( YEAR ( 'Table'[StartDateTime] ), MONTH ( 'Table'[StartDateTime] ), DAY ( 'Table'[StartDateTime] ) )
                + TIME ( HOUR ( 'Table'[StartDateTime] ), 0, 0 ) <= a
                && DATE ( YEAR ( 'Table'[StopDateTime] ), MONTH ( 'Table'[StopDateTime] ), DAY ( 'Table'[StopDateTime] ) )
                    + TIME ( HOUR ( 'Table'[StopDateTime] ), 0, 0 ) >= a
        )
    )
sumr = 
VAR a =
    MAX ( 'except'[DateTime (bins)] )
RETURN
    CALCULATE (
        SUM ( 'Table'[NumPoints] ),
        FILTER (
            ALL ( 'Table' ),
            DATE ( YEAR ( 'Table'[StartDateTime] ), MONTH ( 'Table'[StartDateTime] ), DAY ( 'Table'[StartDateTime] ) )
                + TIME ( HOUR ( 'Table'[StartDateTime] ), 0, 0 ) <= a
                && DATE ( YEAR ( 'Table'[StopDateTime] ), MONTH ( 'Table'[StopDateTime] ), DAY ( 'Table'[StopDateTime] ) )
                    + TIME ( HOUR ( 'Table'[StopDateTime] ), 0, 0 ) >= a
        )
    )

Capture.PNG

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

View solution in original post

4 REPLIES 4
v-frfei-msft
Community Support
Community Support

Hi @D-Jeffrey ,

 

We can create two measures as below.

countid = 
VAR a =
    MAX ( 'except'[DateTime (bins)] )
RETURN
    CALCULATE (
        COUNT ( 'Table'[ID] ),
        FILTER (
            ALL ( 'Table' ),
            DATE ( YEAR ( 'Table'[StartDateTime] ), MONTH ( 'Table'[StartDateTime] ), DAY ( 'Table'[StartDateTime] ) )
                + TIME ( HOUR ( 'Table'[StartDateTime] ), 0, 0 ) <= a
                && DATE ( YEAR ( 'Table'[StopDateTime] ), MONTH ( 'Table'[StopDateTime] ), DAY ( 'Table'[StopDateTime] ) )
                    + TIME ( HOUR ( 'Table'[StopDateTime] ), 0, 0 ) >= a
        )
    )
sumr = 
VAR a =
    MAX ( 'except'[DateTime (bins)] )
RETURN
    CALCULATE (
        SUM ( 'Table'[NumPoints] ),
        FILTER (
            ALL ( 'Table' ),
            DATE ( YEAR ( 'Table'[StartDateTime] ), MONTH ( 'Table'[StartDateTime] ), DAY ( 'Table'[StartDateTime] ) )
                + TIME ( HOUR ( 'Table'[StartDateTime] ), 0, 0 ) <= a
                && DATE ( YEAR ( 'Table'[StopDateTime] ), MONTH ( 'Table'[StopDateTime] ), DAY ( 'Table'[StopDateTime] ) )
                    + TIME ( HOUR ( 'Table'[StopDateTime] ), 0, 0 ) >= a
        )
    )

Capture.PNG

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

@v-frfei-msft This is AWESOME.  I have been battling this forever.  One little problem.  Or maybe it is a feature? 

 

The 5 AM row has the countid and sumr as blank rather than 0.   

 

I think I can deal with that.

 

Power BI rocks!

 

Thanks for the help!

I though I could deal with the hourly gap points, but it is not only when it is 0 by I'm also missing the 3 am data.

 

So the hourly table looks like this:

So an hourly table of the above would look like this:

DateTime (bins)

Count of ID

Total of NumPoints Started

4/2/2019 1:00

0

0

4/2/2019 2:00

2

55

4/2/2019 3:00

2

55

4/2/2019 4:00

2

55

4/2/2019 5:00

0

0

4/2/2019 6:00

2

3

4/2/2019 7:00

4

4

4/2/2019 8:00

4

11

4/2/2019 9:00

3

9

4/2/2019 10:00

1

7

4/2/2019 11:00

1

7

 

The resulting graph is skewed

Snap5.png

So I do I fill in the missing hours? 

 

@v-frfei-msft Is there a way to fill in the hour gaps?

Thanks

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.