cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
Anonymous
Not applicable

Dax expression for multiple tables columns passing as a filter in calculate measure.

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

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

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.

View solution in original post

2 REPLIES 2
v-rzhou-msft
Community Support
Community Support

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.

amitchandak
Super User
Super User

@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

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Dashboard in a day with date

Exclusive opportunity for Women!

Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors