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
I have 4 filters coming from same calendar table. Year, Month, Weeknumber of the month and day
Requirement:
Note: Quantity is a direct column coming from Product table.
Please let me know on how to approach this scenario
Solved! Go to Solution.
@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/
Hi @Anonymous ,
According to your description, I create a sample.
Product table:
Calendar table:
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.
Get the result:
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.
Hi @Anonymous ,
According to your description, I create a sample.
Product table:
Calendar table:
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.
Get the result:
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.
@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/
Above DAX is working only for Month filter. Values are not getting changed for week and day filter.
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
115 | |
95 | |
86 | |
76 | |
64 |
User | Count |
---|---|
138 | |
113 | |
109 | |
98 | |
93 |