Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi. I want to calculate a measure to see required margin for the previous trading day. The dates I have in the table include all dates. I have tried tried a function as shown below. It doesnt show required margin for the previous trading day for weekends and holidays. On the start of the week (monday), it usually shows 0. On the report date it should show the required margin on last friday. How can I make a measure for required margin from the last tradingday when weekends and holidays are excluded?
Solved! Go to Solution.
Hi @LFM
For your question, here is the method I provided:
Here's some dummy data
"NPOSC"
Firstly, you will need a date sheet. This will include the dates of the holidays. And create a relationship between the two tables.
“Holidays”
Create measures.
Search for eligible dates (not weekends and not holidays).
working days =
var _WeekDays = WEEKDAY(SELECTEDVALUE('NPOSC'[Date]), 2)
var _Holidays = SELECTEDVALUE('Holidays'[Holiday date])
var _WorkingDays = IF(_WeekDays < 6 && NOT(_Holidays), SELECTEDVALUE('NPOSC'[Date]), BLANK())
RETURN _WorkingDays
Sort the eligible dates.
Rank Date =
IF(
'NPOSC'[working days] <> BLANK(),
RANKX(FILTER(ALLSELECTED('NPOSC'[Date]), 'NPOSC'[working days] <> BLANK()), 'NPOSC'[working days],,ASC,Dense),
BLANK()
)
Queries the value of the previous trading day.
Previous exposure_mwh =
var _maxrank = MAXX('NPOSC', 'NPOSC'[Rank Date])
RETURN
CALCULATE(
SUM('NPOSC'[exposure_mwh]),
FILTER(
'NPOSC',
'NPOSC'[Rank Date] = _maxrank - 1
)
)
Here is the result.
Regards,
Nono Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @LFM
For your question, here is the method I provided:
Here's some dummy data
"NPOSC"
Firstly, you will need a date sheet. This will include the dates of the holidays. And create a relationship between the two tables.
“Holidays”
Create measures.
Search for eligible dates (not weekends and not holidays).
working days =
var _WeekDays = WEEKDAY(SELECTEDVALUE('NPOSC'[Date]), 2)
var _Holidays = SELECTEDVALUE('Holidays'[Holiday date])
var _WorkingDays = IF(_WeekDays < 6 && NOT(_Holidays), SELECTEDVALUE('NPOSC'[Date]), BLANK())
RETURN _WorkingDays
Sort the eligible dates.
Rank Date =
IF(
'NPOSC'[working days] <> BLANK(),
RANKX(FILTER(ALLSELECTED('NPOSC'[Date]), 'NPOSC'[working days] <> BLANK()), 'NPOSC'[working days],,ASC,Dense),
BLANK()
)
Queries the value of the previous trading day.
Previous exposure_mwh =
var _maxrank = MAXX('NPOSC', 'NPOSC'[Rank Date])
RETURN
CALCULATE(
SUM('NPOSC'[exposure_mwh]),
FILTER(
'NPOSC',
'NPOSC'[Rank Date] = _maxrank - 1
)
)
Here is the result.
Regards,
Nono Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi,
You can create a visual lavel measure using "New Calculation" option which has been introduced few months back. Once you select table visual, that option at top gets enabled.
there you can create a simple measure:
If this resolves your problem, then please mark it as solution. Thanks!
Check out the July 2025 Power BI update to learn about new features.
User | Count |
---|---|
24 | |
9 | |
7 | |
6 | |
6 |
User | Count |
---|---|
29 | |
11 | |
11 | |
10 | |
6 |