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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
nicksinclair01
New Member

Create table with relative dates from slicer

Hi folks,

 

So i want to create a table in Power BI that shows an activity count for the date selected by the user in a drop down.

 

The complicated piece is I then want to show in the next column the sum of the 5 days prior to that selected date and in the last column show the sum of the 20 days prior to that selected date.

 

For example if the user selected 21st April:

RegionDaily CountPrior 5 DaysPrior 20 days
Europe100

500

2000
Japan20010004000
US30015006000

 

My data would be in this format:

DateRegionCount
01/04/2020EUROPE50
01/04/2020US75
01/04/2020JAPAN20
02/04/2020EUROPE30
02/04/2020US

17

02/04/2020JAPAN

72

and so on

 

ANy help would be greatly appreciated.

 

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

Hi @nicksinclair01 ,

I created a sample pbix file(see attachment) for you, please check whether that is what you want.

1. Create a date dimension table

2. Create 3 measures as below to get daily count, the count for prior 5 days and the count for prior 20 days

 

Daily Count = CALCULATE(SUM('Table'[Count]),FILTER('Table','Table'[Date]=SELECTEDVALUE('Date'[Date])))
Prior 5 Days = CALCULATE(SUM('Table'[Count]),DATESBETWEEN('Table'[Date],SELECTEDVALUE('Date'[Date])-5,SELECTEDVALUE('Date'[Date])))
Prior 20 Days = CALCULATE(SUM('Table'[Count]),DATESBETWEEN('Table'[Date],SELECTEDVALUE('Date'[Date])-20,SELECTEDVALUE('Date'[Date])))

 

yingyinr_0-1621934639749.png

You can aslo refer the following video to get it.

Show Days Before Or After A Selected Date - Advanced Power BI Visual Techniques

If the above ones are not what you want, please provide your expected result with backend logic and specific examples. Thank you.

Best Regards

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

View solution in original post

3 REPLIES 3
v-yiruan-msft
Community Support
Community Support

Hi @nicksinclair01 ,

I created a sample pbix file(see attachment) for you, please check whether that is what you want.

1. Create a date dimension table

2. Create 3 measures as below to get daily count, the count for prior 5 days and the count for prior 20 days

 

Daily Count = CALCULATE(SUM('Table'[Count]),FILTER('Table','Table'[Date]=SELECTEDVALUE('Date'[Date])))
Prior 5 Days = CALCULATE(SUM('Table'[Count]),DATESBETWEEN('Table'[Date],SELECTEDVALUE('Date'[Date])-5,SELECTEDVALUE('Date'[Date])))
Prior 20 Days = CALCULATE(SUM('Table'[Count]),DATESBETWEEN('Table'[Date],SELECTEDVALUE('Date'[Date])-20,SELECTEDVALUE('Date'[Date])))

 

yingyinr_0-1621934639749.png

You can aslo refer the following video to get it.

Show Days Before Or After A Selected Date - Advanced Power BI Visual Techniques

If the above ones are not what you want, please provide your expected result with backend logic and specific examples. Thank you.

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
amitchandak
Super User
Super User

@nicksinclair01 , measures like

 

measure =
var _max = maxx(allselected('Date'), 'Date'[Date])
return
calculate(sum(Table[Value]), filter(all('Date'), 'Date'[Date] <=_max && 'Date'[Date] >= _max -5))

 


measure 2=
var _max = maxx(allselected('Date'), 'Date'[Date])
return
calculate(sum(Table[Value]), filter(all('Date'), 'Date'[Date] <=_max && 'Date'[Date] >= _max -20))

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Thank you Amit,

Could you please explain how i would implement this? 

I see i would need a separate table called Date, i assume this would just contain all the inscope dates from the main table.

Does this need to be linked to the main table?

For the slicer, would this be against the main table or the dates table?

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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