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

Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
Anonymous
Not applicable

Display value based on Month, Week and Day filters selection

kruthikav_0-1663599500629.png

I have 4 filters coming from same calendar table. Year, Month, Weeknumber of the month and day

Requirement:

  1. When August month is selected, quantity should display value of last day of pervious month i.e July
  2. When Weeknum filter is selected, quantity should display value for last day of the selected week
  3. When day is selected, quantity should display value of the selected day
  4. If no filter is selected, by default quantity should display value of current day

Note: Quantity is a direct column coming from Product table.
Please let me know on how to approach this scenario

 

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

@Anonymous , try measure like. Assumes year is selected and all date related values are coming from date table

 

var _max = if(isfiltered('Date'),MAX( 'Date'[Date]) , today())
var _weekend = _max+ 7-1*WEEKDAY(_max,2)
return
Switch(True(),
isfiltered(Date[month]), calculate([Measure],,DATESBETWEEN('Date'[Date],eomonth(_max,-1),eomonth(_max,-1))),
isfiltered(Date[month]), calculate([Measure],,DATESBETWEEN('Date'[Date],_weekend,_weekend)),
isfiltered(Date[day]), calculate([Measure],,DATESBETWEEN('Date'[Date],_max,_max)),
calculate([Measure],,DATESBETWEEN('Date'[Date],today(),today())))

 

https://powerpivotpro.com/2013/03/hasonevalue-vs-isfiltered-vs-hasonefilter/

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

View solution in original post

v-yanjiang-msft
Community Support
Community Support

Hi @Anonymous ,

According to your description, I create a sample.

Product table:

vkalyjmsft_0-1663833427801.png

Calendar table:

vkalyjmsft_1-1663833458145.png

Here's my solution.

Don't make relationship between the two tables, create a measure:

Check =
SWITCH (
    TRUE (),
    ISFILTERED ( 'Calendar'[Month] )
        && MAX ( 'Product'[Date] )
            = EOMONTH ( DATE ( 2022, SELECTEDVALUE ( 'Calendar'[Month] ), 1 ), -1 ), 1,
    ISFILTERED ( 'Calendar'[Week] )
        && LOOKUPVALUE ( 'Calendar'[Week], 'Calendar'[Date], MAX ( 'Product'[Date] ) + 1 )
            = SELECTEDVALUE ( 'Calendar'[Week] ) + 1
        && LOOKUPVALUE ( 'Calendar'[Week], 'Calendar'[Date], MAX ( 'Product'[Date] ) )
            = SELECTEDVALUE ( 'Calendar'[Week] ), 1,
    ISFILTERED ( 'Calendar'[Day] )
        && DAY ( MAX ( 'Product'[Date] ) ) = SELECTEDVALUE ( 'Calendar'[Day] ), 1,
    NOT ( ISFILTERED ( 'Calendar' ) )
        && MAX ( 'Product'[Date] ) = TODAY (), 1,
    0
)

Put the measure in the visual filter and select its value to 1.

vkalyjmsft_2-1663833911028.png

Get the result:

vkalyjmsft_3-1663834049183.png

vkalyjmsft_4-1663834065382.png

vkalyjmsft_5-1663834083842.png

vkalyjmsft_6-1663834100643.png

I attach my sample below for your reference.

 

Best Regards,
Community Support Team _ kalyj

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

3 REPLIES 3
v-yanjiang-msft
Community Support
Community Support

Hi @Anonymous ,

According to your description, I create a sample.

Product table:

vkalyjmsft_0-1663833427801.png

Calendar table:

vkalyjmsft_1-1663833458145.png

Here's my solution.

Don't make relationship between the two tables, create a measure:

Check =
SWITCH (
    TRUE (),
    ISFILTERED ( 'Calendar'[Month] )
        && MAX ( 'Product'[Date] )
            = EOMONTH ( DATE ( 2022, SELECTEDVALUE ( 'Calendar'[Month] ), 1 ), -1 ), 1,
    ISFILTERED ( 'Calendar'[Week] )
        && LOOKUPVALUE ( 'Calendar'[Week], 'Calendar'[Date], MAX ( 'Product'[Date] ) + 1 )
            = SELECTEDVALUE ( 'Calendar'[Week] ) + 1
        && LOOKUPVALUE ( 'Calendar'[Week], 'Calendar'[Date], MAX ( 'Product'[Date] ) )
            = SELECTEDVALUE ( 'Calendar'[Week] ), 1,
    ISFILTERED ( 'Calendar'[Day] )
        && DAY ( MAX ( 'Product'[Date] ) ) = SELECTEDVALUE ( 'Calendar'[Day] ), 1,
    NOT ( ISFILTERED ( 'Calendar' ) )
        && MAX ( 'Product'[Date] ) = TODAY (), 1,
    0
)

Put the measure in the visual filter and select its value to 1.

vkalyjmsft_2-1663833911028.png

Get the result:

vkalyjmsft_3-1663834049183.png

vkalyjmsft_4-1663834065382.png

vkalyjmsft_5-1663834083842.png

vkalyjmsft_6-1663834100643.png

I attach my sample below for your reference.

 

Best Regards,
Community Support Team _ kalyj

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

@Anonymous , try measure like. Assumes year is selected and all date related values are coming from date table

 

var _max = if(isfiltered('Date'),MAX( 'Date'[Date]) , today())
var _weekend = _max+ 7-1*WEEKDAY(_max,2)
return
Switch(True(),
isfiltered(Date[month]), calculate([Measure],,DATESBETWEEN('Date'[Date],eomonth(_max,-1),eomonth(_max,-1))),
isfiltered(Date[month]), calculate([Measure],,DATESBETWEEN('Date'[Date],_weekend,_weekend)),
isfiltered(Date[day]), calculate([Measure],,DATESBETWEEN('Date'[Date],_max,_max)),
calculate([Measure],,DATESBETWEEN('Date'[Date],today(),today())))

 

https://powerpivotpro.com/2013/03/hasonevalue-vs-isfiltered-vs-hasonefilter/

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
Anonymous
Not applicable

Above DAX is working only for Month filter. Values are not getting changed for week and day filter.

Helpful resources

Announcements
OCT PBI Update Carousel

Power BI Monthly Update - October 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

October NL Carousel

Fabric Community Update - October 2024

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