cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
justivan
Helper II
Helper II

Filter measure based on Booking Date and Arrival Date

Need help to filter a measure based on booking date and arrival date. The 1st table is the actual value based on the year selected and the 2nd table are all values based on arrival ( I removed the interaction of the slicer ). The objective is to return values of previous years based on the selected year in the slicer of ArrDate. So for example, selected slicer is 2021. I need to return the pax count of the previous years on the same date. How many arrivals do we have in 2020 sold until July 24 2020 and below? How many arrivals do we have on 2019 sold until July 24 2019 below? and so on.

 

Tried this measure but I'm not getting the correct values.

Measure = 
VAR _SelectedYear = SELECTEDVALUE ( ArrDate[Year] )
VAR _DateComparison =  DATE ( _SelectedYear - 1, MONTH ( TODAY ()), DAY ( TODAY ()) )
RETURN
    CALCULATE (
        [Pax Count],
        FILTER ( 'ResDate', 'ResDate'[Date] <= _DateComparison )
    )

justivan_1-1627083712076.png

2 Calendar Tables

justivan_0-1627083673637.png

 

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

Hi @justivan ,

 

After my research, there is no need to establish a relationship between the calendar table and the main table.

This is my example, you can refer to it.

Main table:

6.png

Calendar table:

calendar = ADDCOLUMNS(CALENDAR(MIN('Table'[Date]),MAX('Table'[Date])),"Year",YEAR([Date]))

7.png

8.png

 

Create the following measure

Measure =
VAR _sel =
    SELECTEDVALUE ( 'calendar'[Year] )
RETURN
    CALCULATE (
        SUM ( 'Table'[Value] ),
        FILTER (
            'Table',
            (
                [Date]
                    <= DATE ( _sel - 1, MONTH ( TODAY () ), DAY ( TODAY () ) )
                    && [Date]
                        >= DATE ( _sel - 1, 1, 1 )
            )
                || (
                    [Date]
                        <= DATE ( _sel - 2, MONTH ( TODAY () ), DAY ( TODAY () ) )
                        && [Date]
                            >= DATE ( _sel - 2, 1, 1 )
                )
        )
    )

9.png

Check more details from the attachment.

 

 

Best Regards,

Stephen Tao

 

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-stephen-msft
Community Support
Community Support

Hi @justivan ,

 

After my research, there is no need to establish a relationship between the calendar table and the main table.

This is my example, you can refer to it.

Main table:

6.png

Calendar table:

calendar = ADDCOLUMNS(CALENDAR(MIN('Table'[Date]),MAX('Table'[Date])),"Year",YEAR([Date]))

7.png

8.png

 

Create the following measure

Measure =
VAR _sel =
    SELECTEDVALUE ( 'calendar'[Year] )
RETURN
    CALCULATE (
        SUM ( 'Table'[Value] ),
        FILTER (
            'Table',
            (
                [Date]
                    <= DATE ( _sel - 1, MONTH ( TODAY () ), DAY ( TODAY () ) )
                    && [Date]
                        >= DATE ( _sel - 1, 1, 1 )
            )
                || (
                    [Date]
                        <= DATE ( _sel - 2, MONTH ( TODAY () ), DAY ( TODAY () ) )
                        && [Date]
                            >= DATE ( _sel - 2, 1, 1 )
                )
        )
    )

9.png

Check more details from the attachment.

 

 

Best Regards,

Stephen Tao

 

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

Ashish_Mathur
Super User
Super User

Hi,

We do not need the ResDate table.  In your second visual, drag Year and Month from the ArrDate table.  Write this measure

=calculate([Pax count],datesbetween(Arrdate,min(arrDate),date(min(arrdate[year]),min(arrdate[monthnum]),day(today()))))

Hope this helps.


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

Hi @Ashish_Mathur ,

Thanks for your response.

I tried the above expression but I'm getting an error.

justivan_0-1627110870701.png

 

Hi,

Try this

=calculate([Pax count],datesbetween(Arrdate[date],min(arrDate[date]),date(min(arrdate[year]),min(arrdate[monthnum]),day(today()))))


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

Helpful resources

Announcements
UG GA Amplification 768x460.png

Launching new user group features

Learn how to create your own user groups today!

Power BI October Update 2021.jpg

Power BI Release

Click here to read more about the October 2021 Release!

Community Connections 768x460.jpg

Community & How To Videos

Check out the new Power Platform Community Connections gallery!

Teds Dev Camp Oct. 2021 768x460.jpg

Power BI Dev Camp - October 28th, 2021

Mark your calendars and join us for our next Power BI Dev Camp!