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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
LFM
Helper I
Helper I

Calculate values for the previous trading day when weekends are excluded

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?

Skjermbilde 2024-04-15 112929.png
Function previous exposure.png

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

Hi @LFM 

 

For your question, here is the method I provided:

 

Here's some dummy data

 

"NPOSC"

vnuocmsft_0-1713774399855.png

 

Firstly, you will need a date sheet. This will include the dates of the holidays. And create a relationship between the two tables.

 

“Holidays”

vnuocmsft_1-1713774514026.png

 

vnuocmsft_2-1713774714510.png

 

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

 

vnuocmsft_3-1713774864537.png

 

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()   
)

 

vnuocmsft_4-1713774976692.png

 

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.

 

vnuocmsft_5-1713775155395.png

 

Regards,

Nono Chen

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

2 REPLIES 2
v-nuoc-msft
Community Support
Community Support

Hi @LFM 

 

For your question, here is the method I provided:

 

Here's some dummy data

 

"NPOSC"

vnuocmsft_0-1713774399855.png

 

Firstly, you will need a date sheet. This will include the dates of the holidays. And create a relationship between the two tables.

 

“Holidays”

vnuocmsft_1-1713774514026.png

 

vnuocmsft_2-1713774714510.png

 

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

 

vnuocmsft_3-1713774864537.png

 

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()   
)

 

vnuocmsft_4-1713774976692.png

 

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.

 

vnuocmsft_5-1713775155395.png

 

Regards,

Nono Chen

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

 

samratpbi
Solution Supplier
Solution Supplier

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:

Prev Sales =
 PREVIOUS([Sales])
That will give you all previous day's sale including weekends.
Using your date dimension table, you can filter out weekends. usually Date dimension table should have week no, you may use that to filter it out. PREVIOUS function will autometically consider previous weekday's value.
samratpbi_0-1713276094488.png

If this resolves your problem, then please mark it as solution. Thanks!

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors