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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
JohnSpartan
Regular Visitor

How to count occupation Dates

Dear All,

 

First time posting !!

 

I´m preparing a report and I´m really stuck with something.

 

I have a hotel with some room and I have to calculate how many days the room has been ocupied during a specify period (IE. January)

 

RoomDate FromTo
12326/12/201606/01/2017
12313/01/201721/01/2017
12327/01/201706/02/2017

 

Somebody can help me ??

 

Thanks in advance

2 ACCEPTED SOLUTIONS
v-shex-msft
Community Support
Community Support

Hi @JohnSpartan,

 

You can refer to below sample to achieve your requirement.

 

1. Create a calendar table based on record table.

CALENDAR = CALENDAR(FIRSTDATE(Records[Date From]),LASTDATE(Records[To]))

 

2. Write a measure to calculate the occupation date count.

Dynamic Count = 
VAR current_Date =
    MAX ( 'CALENDAR'[Date] )
VAR stare_date =
    DATE ( YEAR ( current_Date ), MONTH ( current_Date ), 1 )
VAR end_date =
    DATE ( YEAR ( current_Date ), MONTH ( current_Date ) + 1, 1 )
        - 1
VAR filtered =
    FILTER (
        ALL ( Records ),
        CONTAINS (
            ADDCOLUMNS (
                CALENDAR ( [Date From], [To] ),
                "YearMonth", FORMAT ( [Date], "mmm/yyyy" )
            ),
            [YearMonth], FORMAT ( current_Date, "mmm/yyyy" )
        )
    )
RETURN
    SUMX (
        ADDCOLUMNS (
            ADDCOLUMNS (
                filtered,
                "StartDat", IF ( [Date From] <= stare_date, stare_date, [Date From] ),
                "EndDate", IF ( [To] >= end_date, end_date, [To] )
            ),
            "Diff", DATEDIFF ( [StartDat], [EndDate], DAY )
        ),
        [Diff]
    )

 

3. Use measure and calendar date to create visuals.

5.PNG

 

Comment:

VAR stare_date =
DATE ( YEAR ( current_Date ), MONTH ( current_Date ), 1 )
VAR end_date =
DATE ( YEAR ( current_Date ), MONTH ( current_Date ) + 1, 1 )
- 1
find out the startdate and enddate of current month.

 

VAR filtered =
FILTER (
ALL ( Records ),
CONTAINS (
ADDCOLUMNS (
CALENDAR ( [Date From], [To] ),
"YearMonth", FORMAT ( [Date], "mmm/yyyy" )
),
[YearMonth], FORMAT ( current_Date, "mmm/yyyy" )
)
)
filter related records based on year month of current date.

 

ADDCOLUMNS (
ADDCOLUMNS (
filtered,
"StartDat", IF ( [Date From] <= stare_date, stare_date, [Date From] ),
"EndDate", IF ( [To] >= end_date, end_date, [To] )
),
"Diff", DATEDIFF ( [StartDat], [EndDate], DAY )
)
Dynamic compare the current record date with variable start_date/end_date, add columns to store these correct date and calculate the date diff.

 

Notice: I attach the pbix file below.

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

Ashish_Mathur
Super User
Super User

Hi,

 

You may refer to my solution here.

 

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

4 REPLIES 4
Ashish_Mathur
Super User
Super User

Hi,

 

You may refer to my solution here.

 

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

hi All 

i revive this thread just to ask how we can show the occupancy as percentage vs month/quarter/year. 

i actually try to divide the number of days that the room is booked with the number of available days in each given period. 

i tryied with eomonth function but with no chance

Is there anyway to do so? 

Hi,

 

Share some data and show the expected result.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
v-shex-msft
Community Support
Community Support

Hi @JohnSpartan,

 

You can refer to below sample to achieve your requirement.

 

1. Create a calendar table based on record table.

CALENDAR = CALENDAR(FIRSTDATE(Records[Date From]),LASTDATE(Records[To]))

 

2. Write a measure to calculate the occupation date count.

Dynamic Count = 
VAR current_Date =
    MAX ( 'CALENDAR'[Date] )
VAR stare_date =
    DATE ( YEAR ( current_Date ), MONTH ( current_Date ), 1 )
VAR end_date =
    DATE ( YEAR ( current_Date ), MONTH ( current_Date ) + 1, 1 )
        - 1
VAR filtered =
    FILTER (
        ALL ( Records ),
        CONTAINS (
            ADDCOLUMNS (
                CALENDAR ( [Date From], [To] ),
                "YearMonth", FORMAT ( [Date], "mmm/yyyy" )
            ),
            [YearMonth], FORMAT ( current_Date, "mmm/yyyy" )
        )
    )
RETURN
    SUMX (
        ADDCOLUMNS (
            ADDCOLUMNS (
                filtered,
                "StartDat", IF ( [Date From] <= stare_date, stare_date, [Date From] ),
                "EndDate", IF ( [To] >= end_date, end_date, [To] )
            ),
            "Diff", DATEDIFF ( [StartDat], [EndDate], DAY )
        ),
        [Diff]
    )

 

3. Use measure and calendar date to create visuals.

5.PNG

 

Comment:

VAR stare_date =
DATE ( YEAR ( current_Date ), MONTH ( current_Date ), 1 )
VAR end_date =
DATE ( YEAR ( current_Date ), MONTH ( current_Date ) + 1, 1 )
- 1
find out the startdate and enddate of current month.

 

VAR filtered =
FILTER (
ALL ( Records ),
CONTAINS (
ADDCOLUMNS (
CALENDAR ( [Date From], [To] ),
"YearMonth", FORMAT ( [Date], "mmm/yyyy" )
),
[YearMonth], FORMAT ( current_Date, "mmm/yyyy" )
)
)
filter related records based on year month of current date.

 

ADDCOLUMNS (
ADDCOLUMNS (
filtered,
"StartDat", IF ( [Date From] <= stare_date, stare_date, [Date From] ),
"EndDate", IF ( [To] >= end_date, end_date, [To] )
),
"Diff", DATEDIFF ( [StartDat], [EndDate], DAY )
)
Dynamic compare the current record date with variable start_date/end_date, add columns to store these correct date and calculate the date diff.

 

Notice: I attach the pbix file below.

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

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

MayPowerBICarousel

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.