The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I have few tables - Date, Store, Item , product tables
From Date Table - Date(YEAR), Date(Month)
From Store Table - Store(RUName)
From Item Table - Item(itemName)
From Product Table - Product(ProductName)
And Now I have one Measure ie., [SP]
I am trying to retrieve the [SP] data with all above filter values
Can I get some logic, how I can pass all those filters in DAX
Solved! Go to Solution.
Hi @Anonymous ,
I think there should be a data table with [Year], [Month] or [YearMonth]/[Date],[RUName],[ItemName],[ProductName] and [Value] columns in it. Measure [SP] is based on [Value] column in data table.
So, if you create relationships as amitchandak mentioned, you can filter [SP] measure by slicer or filter by columns in these four tables.
Relationship Sample should looks like as below. These four tables are Dim tables.
Date[YearMonth]/[Date] - Data[YearMonth]/[Date]
Store[RUName] - Data[RUName]
Item[itemName] - Data[itemName]
Product[ProductName] - Data[ProductName]
If Date table and Data table only has [Year] and [Month] instead of [YearMonth] or [Date]. There could only be one active relationship. So you can try USERELATIONSHIO function in DAX.
SP =
CALCULATE (
SUM ( 'Data'[Value] ),
USERELATIONSHIP ( 'Date'[Month], 'Data'[Month] )
)
If there are no relationships between your Data table and these four Dimtables, you can try this code.
SP =
VAR _SELECTYEAR =
VALUES ( 'Date'[Year] )
VAR _SELECTMONTH =
VALUES ( 'Date'[Month] )
VAR _SELECTRUName =
VALUES ( 'Store'[RUName] )
VAR _SELECTItemName =
VALUES ( 'Item'[itemName] )
VAR _SELECTProductName =
VALUES ( 'Product'[ProductName] )
RETURN
CALCULATE (
SUM ( 'Data'[Value] ),
FILTER (
'Data',
'Data'[Year]
IN _SELECTYEAR
&& 'Data'[Month]
IN _SELECTMONTH
&& 'Data'[RUName]
IN _SELECTRUName
&& 'Data'[itemName]
IN _SELECTItemName
&& 'Data'[ProductName] IN _SELECTProductName
)
)
Then you can filter [SP] by slicers or filters from columns in these four dimtables as well.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
I think there should be a data table with [Year], [Month] or [YearMonth]/[Date],[RUName],[ItemName],[ProductName] and [Value] columns in it. Measure [SP] is based on [Value] column in data table.
So, if you create relationships as amitchandak mentioned, you can filter [SP] measure by slicer or filter by columns in these four tables.
Relationship Sample should looks like as below. These four tables are Dim tables.
Date[YearMonth]/[Date] - Data[YearMonth]/[Date]
Store[RUName] - Data[RUName]
Item[itemName] - Data[itemName]
Product[ProductName] - Data[ProductName]
If Date table and Data table only has [Year] and [Month] instead of [YearMonth] or [Date]. There could only be one active relationship. So you can try USERELATIONSHIO function in DAX.
SP =
CALCULATE (
SUM ( 'Data'[Value] ),
USERELATIONSHIP ( 'Date'[Month], 'Data'[Month] )
)
If there are no relationships between your Data table and these four Dimtables, you can try this code.
SP =
VAR _SELECTYEAR =
VALUES ( 'Date'[Year] )
VAR _SELECTMONTH =
VALUES ( 'Date'[Month] )
VAR _SELECTRUName =
VALUES ( 'Store'[RUName] )
VAR _SELECTItemName =
VALUES ( 'Item'[itemName] )
VAR _SELECTProductName =
VALUES ( 'Product'[ProductName] )
RETURN
CALCULATE (
SUM ( 'Data'[Value] ),
FILTER (
'Data',
'Data'[Year]
IN _SELECTYEAR
&& 'Data'[Month]
IN _SELECTMONTH
&& 'Data'[RUName]
IN _SELECTRUName
&& 'Data'[itemName]
IN _SELECTItemName
&& 'Data'[ProductName] IN _SELECTProductName
)
)
Then you can filter [SP] by slicers or filters from columns in these four dimtables as well.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@Anonymous , if the table which has the base columns [SP] is joined with these tables/dimensions. And these dimensions are fitting that table (on the many side in on to many, and have bi-direction join in case of many to many). Then slicer should automatically filter the measure
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
21 | |
20 | |
18 | |
17 | |
13 |
User | Count |
---|---|
41 | |
38 | |
24 | |
22 | |
20 |