cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Helper IV
Helper IV

Date table in a Power BI report

Hi,

 

I have a table as below:

 

data_DateIntramonthAttributeValue
31/01/202031-Jan-20KIDS20%
31/01/202031-Jan-20TEACHERS30%
31/01/202031-Jan-20Admin Staff40%
28/02/202028-Feb-20KIDS0.00%
28/02/202028-Feb-20TEACHERS100%
28/02/202028-Feb-20Admin Staff23%
31/03/202031/03/2020KIDS40%
31/03/202031/03/2020TEACHERS23%
31/03/202031/03/2020Admin Staff45%
30/04/202030/04/2020KIDS23%
30/04/202030/04/2020TEACHERS67%
30/04/202030/04/2020Admin Staff70%
29/05/202029/05/2020KIDS56%
29/05/202029/05/2020TEACHERS98%
29/05/202029/05/2020Admin Staff35%
30/06/202030/06/2020KIDS56%
30/06/202030/06/2020TEACHERS34%
30/06/202030/06/2020Admin Staff56%
31/07/202031/07/2020KIDS67%
31/07/202031/07/2020TEACHERS23%
31/07/202031/07/2020Admin Staff45%

 

My final output needs to have a datepicker which has all distinct dates. Based onn the date selected, it needs to display data for previous 4 months: In the screenshot below, I've selected 31/07/2020 in the date picker, so I get output for the previous 3 months. The selected date is displayed as intra-month

 

 
     
 Intra-Month30/06/202029/05/202030/04/2020
Kids67%56%56%23%

 

If I select, 29/05/2020, I get the following results in the Kids table:

 Intra-Month30/04/202031/03/202028-Feb-20
Kids56%23%40%0%

 

 

I've created a Date table to map the selected date to previous months using the Power BI query below:

Table = ADDCOLUMNS(CALENDARAUTO(),"MONTH",MONTH([Date]),"Year",YEAR([Date]),"Last working day",EOMONTH([Date],0)-if(WEEKDAY(EOMONTH([Date],0),2)<=5,0,if(WEEKDAY(EOMONTH([Date],0),2)=6,1,2)),"PREV",EOMONTH(([Date]),1)-if(WEEKDAY(EOMONTH([Date],1),2)<=5,0,if(WEEKDAY(EOMONTH([Date],1),2)=6,1,2)),"PREV MONTH",EOMONTH(([Date]),2)-if(WEEKDAY(EOMONTH([Date],2),2)<=5,0,if(WEEKDAY(EOMONTH([Date],2),2)=6,1,2)),"PREV MONTH2",EOMONTH(([Date]),3)-if(WEEKDAY(EOMONTH([Date],3),2)<=5,0,if(WEEKDAY(EOMONTH([Date],3),2)=6,1,2)))
 
I cant get the 2 tables to connect to display dates as column headers and values as shown in the desired output.
 
Any help is greatly appreciated.
 
 
1 ACCEPTED SOLUTION
Community Support
Community Support

Hi @ara_4 

I use your to table and build a measure to achieve your goal.

Build a silcer by Last working day column in Date Table, then build a measure.

Measure = 
VAR _selectedcolumn =
    SELECTEDVALUE ( Table2[Last working day] )
VAR _Datediff =
    DATEDIFF ( MAX ( 'Table1'[data_Date] ), _selectedcolumn, MONTH )
RETURN
    IF (
        _Datediff >= 0
            && _Datediff < 4,
        CALCULATE ( SUM ( 'Table1'[Value] ) ),
        BLANK ()
    )

Build a matrix visual as below:

1.png

Result:

Select 2020/07/31

2.png

Select 2020/05/29

3.png

You can download the pbix file from this link: Date table in a Power BI report

 

Best Regards,

Rico Zhou

 

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
Community Support
Community Support

Hi @ara_4 

Could you tell me if your problem has been solved? If it is, kindly Accept it as the solution. More people will benefit from it. Or you are still confused about it, please provide me with more details about your problem or share me with your pbix file from your Onedrive for Business.

 

Best Regards,

Rico Zhou

Community Support
Community Support

Hi @ara_4 

I use your to table and build a measure to achieve your goal.

Build a silcer by Last working day column in Date Table, then build a measure.

Measure = 
VAR _selectedcolumn =
    SELECTEDVALUE ( Table2[Last working day] )
VAR _Datediff =
    DATEDIFF ( MAX ( 'Table1'[data_Date] ), _selectedcolumn, MONTH )
RETURN
    IF (
        _Datediff >= 0
            && _Datediff < 4,
        CALCULATE ( SUM ( 'Table1'[Value] ) ),
        BLANK ()
    )

Build a matrix visual as below:

1.png

Result:

Select 2020/07/31

2.png

Select 2020/05/29

3.png

You can download the pbix file from this link: Date table in a Power BI report

 

Best Regards,

Rico Zhou

 

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

Super User IV
Super User IV

@ara_4 , if select 1 date or set of date but want more data then that refer

https://www.youtube.com/watch?v=duMSovyosXE

 

if you simply want rolling you can use with date table

Rolling 3 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date],ENDOFMONTH(Sales[Sales Date]),-3,MONTH))
Rolling 3 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date],max(Sales[Sales Date]),-3,MONTH))
Rolling 3 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date],startofmonth(Sales[Sales Date]),-3,MONTH))

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.

 

 



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Helpful resources

Announcements
secondImage

Happy New Year from Power BI

This is a must watch for a message from Power BI!

December Update

Check it Out!

Click here to read more about the December 2020 Updates!

Community Blog

Check it Out!

Click here to read the latest blog and learn more about contributing to the Power BI blog!

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

Mark your calendars and join us for our next Power BI Dev Camp!.

Top Solution Authors
Top Kudoed Authors