Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet 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
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:
Region | Daily Count | Prior 5 Days | Prior 20 days |
Europe | 100 | 500 | 2000 |
Japan | 200 | 1000 | 4000 |
US | 300 | 1500 | 6000 |
My data would be in this format:
Date | Region | Count |
01/04/2020 | EUROPE | 50 |
01/04/2020 | US | 75 |
01/04/2020 | JAPAN | 20 |
02/04/2020 | EUROPE | 30 |
02/04/2020 | US | 17 |
02/04/2020 | JAPAN | 72 |
and so on
ANy help would be greatly appreciated.
Solved! Go to Solution.
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])))
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
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])))
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
@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))
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?
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
86 | |
85 | |
84 | |
67 | |
49 |
User | Count |
---|---|
131 | |
111 | |
97 | |
71 | |
67 |