Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
Check it out now!Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hi
For this week (today 23th august 2021) - I want to display two dates i.e last two fridays
1) Last Friday i.e 08/20/2021
2) Last Friday before 20th August,2021 i.e 08/13/2021
Can someone please help me with the DAX?
Thank you in advance.
Solved! Go to Solution.
OK. First create a Calendar Table.
Calendar Table =
VAR MinD =
DATE ( 2020, 12, 01 ) // subsitute for the expression for the minimum date in you model, as in MIN(Table1[Date])
VAR MaxD =
DATE ( 2021, 10, 31 ) // subsitute for the expression for the maximum date in you model, as in MAX(Table2[Date]) - if the min and max dates are in the same table, use the same table expression.
RETURN
ADDCOLUMNS (
CALENDAR ( MinD, MaxD ),
"WeekDay", WEEKDAY ( [Date], 2 ),
"WeekNum", WEEKNUM ( [Date] ),
"Year", YEAR ( [Date] ),
"YearWeek",
YEAR ( [Date] ) * 100
+ WEEKNUM ( [Date] )
)
Add a new calculated column to this table to establish an index for the YearWeek field using:
Index =
RANKX('Calendar Table', 'Calendar Table'[YearWeek],,ASC,Dense)
And you should get this final Calendar Table:
Now create the measure you need:
Last Friday =
VAR YearWeek =
CALCULATE (
MAX ( 'Calendar Table'[Index] ),
FILTER ( 'Calendar Table' , 'Calendar Table'[Date] = TODAY () )
)
RETURN
CALCULATE (
MAX ( 'Calendar Table'[Date] ),
FILTER (
'Calendar Table',
'Calendar Table'[Index] = YearWeek - 1
&& 'Calendar Table'[WeekDay] = 5
)
)
And...
2 Friday Ago =
VAR YearWeek =
CALCULATE (
MAX ( 'Calendar Table'[Index] ),
FILTER ( 'Calendar Table' , 'Calendar Table'[Date] = TODAY () )
)
RETURN
CALCULATE (
MAX ( 'Calendar Table'[Date] ),
FILTER (
'Calendar Table',
'Calendar Table'[Index] = YearWeek - 2
&& 'Calendar Table'[WeekDay] = 5
)
)
And you will get this:
Proud to be a Super User!
Paul on Linkedin.
Happy to have helped.
BTW, if you have date fields in your model you should be using the Calendar table as a dimension table by creating relationships with the corresponding date fields in your model. You can the use Time Intelligence functions in measures, and the fields from the Calendar table in your visuals, filters, slicers, measures etc
Proud to be a Super User!
Paul on Linkedin.
do you have a Calendar or Date table? Also, does the week begin on Sunday or Monday?
Proud to be a Super User!
Paul on Linkedin.
I dont have a calendar nor date table. But I can definately create on based on your suggestion.
you need one. Also, does the week start on Sunday or Monday?
Proud to be a Super User!
Paul on Linkedin.
Anything would work. As far as I get to the friday's date
OK. First create a Calendar Table.
Calendar Table =
VAR MinD =
DATE ( 2020, 12, 01 ) // subsitute for the expression for the minimum date in you model, as in MIN(Table1[Date])
VAR MaxD =
DATE ( 2021, 10, 31 ) // subsitute for the expression for the maximum date in you model, as in MAX(Table2[Date]) - if the min and max dates are in the same table, use the same table expression.
RETURN
ADDCOLUMNS (
CALENDAR ( MinD, MaxD ),
"WeekDay", WEEKDAY ( [Date], 2 ),
"WeekNum", WEEKNUM ( [Date] ),
"Year", YEAR ( [Date] ),
"YearWeek",
YEAR ( [Date] ) * 100
+ WEEKNUM ( [Date] )
)
Add a new calculated column to this table to establish an index for the YearWeek field using:
Index =
RANKX('Calendar Table', 'Calendar Table'[YearWeek],,ASC,Dense)
And you should get this final Calendar Table:
Now create the measure you need:
Last Friday =
VAR YearWeek =
CALCULATE (
MAX ( 'Calendar Table'[Index] ),
FILTER ( 'Calendar Table' , 'Calendar Table'[Date] = TODAY () )
)
RETURN
CALCULATE (
MAX ( 'Calendar Table'[Date] ),
FILTER (
'Calendar Table',
'Calendar Table'[Index] = YearWeek - 1
&& 'Calendar Table'[WeekDay] = 5
)
)
And...
2 Friday Ago =
VAR YearWeek =
CALCULATE (
MAX ( 'Calendar Table'[Index] ),
FILTER ( 'Calendar Table' , 'Calendar Table'[Date] = TODAY () )
)
RETURN
CALCULATE (
MAX ( 'Calendar Table'[Date] ),
FILTER (
'Calendar Table',
'Calendar Table'[Index] = YearWeek - 2
&& 'Calendar Table'[WeekDay] = 5
)
)
And you will get this:
Proud to be a Super User!
Paul on Linkedin.
Thank you. This is super-helpful.
Happy to have helped.
BTW, if you have date fields in your model you should be using the Calendar table as a dimension table by creating relationships with the corresponding date fields in your model. You can the use Time Intelligence functions in measures, and the fields from the Calendar table in your visuals, filters, slicers, measures etc
Proud to be a Super User!
Paul on Linkedin.