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

Shape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.

Reply
CloudMonkey
Post Prodigy
Post Prodigy

Calculating the total number of Vehicle Service Days that are on Public Holidays

Hello,

 

I have uploaded my pbix file at https://we.tl/t-O7u7D4I8i5 

 

I have 3 unlinked tables (sorry it's not possible to link the tables for other reasons, I don't have control of that unfortunately):

 - Calendar (months)

 - Public Holidays

 - List of vehicles servicings with service dates

 

For each Calendar month, please can you tell me how to create a calculated measure to return the total number of vehicle service days that were public holidays? (it can't be a calculate column because I need to filter by other categories later on)

 

This is where I got to but I have to confess I am stuggling without the table relationships (the answer should be 0 in November, 6 in December (3 cars each being serviced on both 25th and 26th December), 0 in January)

CloudMonkey_0-1626100297178.png

Thank you for any help,

CM

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

Hi @CloudMonkey ,

 

I think you'd better have holiday data for each year, so I replace 2021 with 2020 year.

 

vkkfmsft_0-1626254537798.png

 

Then I create the following measures:

 

Measure = 
COUNTROWS(
    FILTER(
        'Vehicles Being Serviced',
        'Vehicles Being Serviced'[Date Taken Off Road] < MAX('Public Holidays'[Date])
        && 'Vehicles Being Serviced'[Date Returned] >= MAX('Public Holidays'[Date])
    )
)
Number of Vehicle Service Days that are Public Holidays = 
VAR FirstDayOfMonth = min('Calendar (Months)'[Month Start Date])
VAR FirstDayOfNextMonth = edate(FirstDayOfMonth,1)

RETURN
CALCULATE(
    SUMX( ALLSELECTED('Public Holidays'[Date]), [Measure] ), 
    FILTER(
        'Public Holidays',
        'Public Holidays'[Public Holiday Flag] =1 
        && 'Public Holidays'[Date] < FirstDayOfNextMonth
        && 'Public Holidays'[Date] >= FirstDayOfMonth
    )
)

image.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

4 REPLIES 4
v-kkf-msft
Community Support
Community Support

Hi @CloudMonkey ,

 

I think you'd better have holiday data for each year, so I replace 2021 with 2020 year.

 

vkkfmsft_0-1626254537798.png

 

Then I create the following measures:

 

Measure = 
COUNTROWS(
    FILTER(
        'Vehicles Being Serviced',
        'Vehicles Being Serviced'[Date Taken Off Road] < MAX('Public Holidays'[Date])
        && 'Vehicles Being Serviced'[Date Returned] >= MAX('Public Holidays'[Date])
    )
)
Number of Vehicle Service Days that are Public Holidays = 
VAR FirstDayOfMonth = min('Calendar (Months)'[Month Start Date])
VAR FirstDayOfNextMonth = edate(FirstDayOfMonth,1)

RETURN
CALCULATE(
    SUMX( ALLSELECTED('Public Holidays'[Date]), [Measure] ), 
    FILTER(
        'Public Holidays',
        'Public Holidays'[Public Holiday Flag] =1 
        && 'Public Holidays'[Date] < FirstDayOfNextMonth
        && 'Public Holidays'[Date] >= FirstDayOfMonth
    )
)

image.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

 

amitchandak
Super User
Super User

@CloudMonkey , My idea would be to create a new column in the calendar to have flag public holidays.

 

We can join calendar and vehicles  on date and service date(without time)

 

Then we can have

 

calculate(countrows(vehicles), filter(Calendar, Calendar[Holiday] =1))

 

check if needed

 

refer 4 ways to copy data from one table to another
https://www.youtube.com/watch?v=Wu1mWxR23jU
https://www.youtube.com/watch?v=czNHt7UXIe8

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Thanks @amitchandak but as I say I'm not allowed to combined the tables, is there another way? Thanks

@CloudMonkey , Assume calendar is going to control the date

 

Try a measure like

new measure =
VAR _min = MINX( allselected('Calendar') , 'Calendar'[Date] )
VAR _max = MAXX(allselected('Calendar') , 'Calendar'[Date] )
var _tab = filter('Public Holidays', 'Public Holidays'[Date] >= _min && 'Public Holidays'[Date] <= _max && 'Public Holidays'[Holiday] =1)
return
calculate(countrows(vehicles), filter(vehicles, vehicles[date] in _tab))

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.