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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
Anonymous
Not applicable

Power BI date extrapolation

I have a table showing people's names, a start date and an end date. I am wanting to make a plot where it shows when (in the past 6 months) people have been active.

My table looks something like

NAME   |  Start   |   End

---------------------------

Bob . |   2019-02-01 . | 2019-08-23

Joe .  | .2011-05-15 . | 2019-08-28

John | 2017-02-5 . | 2018-05-08

 

And what I am hoping to make is a table (for plotting) like this

 

DATE .     | .   # of active users

---------------------------------

2011-04 .  | .    0

2011-05 .  |     1 .    (where joe starts)

2011-06 .  | .   1

...

2017-01 . | .    1

2017-02 . |      2 .   (where john starts)

2017-03 . | .    2

...

2018-04 . | .   2

2018-05  | .    2 .   (where John stops)

2018-06 . | .    1

...

2019-01 . | .    1

2019-02  | .    2 .     (Bob starts)

2019-03 . | .    2

...

2019-07 . | .   2

2019-08 . | .    2 .  (both Bob and Joe stop)

2019-09   |     0

 

I can't seem to get Power BI to behave when it comes to date extrapolations. Any help is greatly appreciated!

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

Hi @Anonymous ,

 

At first, you need a calendar table.

Date =
CALENDAR ( MIN ( 'Status'[Start] ), MAX ( 'Status'[End] ) )

Then add a column to get YEAR&MONTH.

YM =
YEAR ( 'Date'[Date] ) * 100
    + MONTH ( 'Date'[Date] )

Then add column “startYM” and column “endYM”  in another table which contains names.

StartYM =
YEAR ( 'Status'[Start] ) * 100
    + MONTH ( 'Status'[Start] )
EndYM =
YEAR ( 'Status'[End] ) * 100
    + MONTH ( 'Status'[End] )

Cross join two tables.

Table =
CROSSJOIN ( DISTINCT ( SELECTCOLUMNS ( 'Date', "YM", 'Date'[YM] ) ), 'Status' )

Add a new column to get the count and use a new measure to sum it.

count =
IF ( 'Table'[YM] >= 'Table'[StartYM] && 'Table'[YM] <= 'Table'[EndYM], 1, 0 )
Measure =
SUM ( 'Table'[count] )

Now , you can use visuals to get result.3-1.PNG

 

Best Regards,

Eads

 

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

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

View solution in original post

1 REPLY 1
v-eachen-msft
Community Support
Community Support

Hi @Anonymous ,

 

At first, you need a calendar table.

Date =
CALENDAR ( MIN ( 'Status'[Start] ), MAX ( 'Status'[End] ) )

Then add a column to get YEAR&MONTH.

YM =
YEAR ( 'Date'[Date] ) * 100
    + MONTH ( 'Date'[Date] )

Then add column “startYM” and column “endYM”  in another table which contains names.

StartYM =
YEAR ( 'Status'[Start] ) * 100
    + MONTH ( 'Status'[Start] )
EndYM =
YEAR ( 'Status'[End] ) * 100
    + MONTH ( 'Status'[End] )

Cross join two tables.

Table =
CROSSJOIN ( DISTINCT ( SELECTCOLUMNS ( 'Date', "YM", 'Date'[YM] ) ), 'Status' )

Add a new column to get the count and use a new measure to sum it.

count =
IF ( 'Table'[YM] >= 'Table'[StartYM] && 'Table'[YM] <= 'Table'[EndYM], 1, 0 )
Measure =
SUM ( 'Table'[count] )

Now , you can use visuals to get result.3-1.PNG

 

Best Regards,

Eads

 

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

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.