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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

DAX help - filter another table based on value in current row

I have two fact tables, one with info about Purchases, and the other with info about Purchases Forecast. Here's a simplified look at the data model:

 

Data Model.PNG

 

And here's a sample of data for the Purchases and Purchases Forecast tables

 

PurchasesPurchasesPurchases ForecastPurchases Forecast

 

1. Not all purchases have a forecast (see reception 4002). 

2. Reception No has same date and vendor in both purchase and forecast table.

3. Reception No might have different items between purchases and forecast (see reception 4003). 

4. 

 

I want to:

1. Calculate Purchase Quantity for the reception no in Purchase Forecast. So, in a way, when I filter by reception no in purchases forecast, I want the purchase quantity to be filtered for the equivalent reception no in Purchases table.

PurchasesFilter.PNG

And I want the Purchase Quantity to be calculated only for the reception no(s) that actually have a forecast. So, for example, if I select a vendor, I would like to see actual compared to forecast based on reception no that have a forecast. For Vendor 2, I don't want to see data from reception 4002. If a vendor delivers an item that is not part of the forecast, but is part of the same reception no, then I want to see this info (see vendor 4).

 

2. Calculate Difference between forecast and actual as absolute value. When I look at a vendor, I want to be able to see the difference on reception no level. So if I look on vendor 2, it looks like item 3 was forecasted correctly. But on reception 4001 the difference is 50 and on reception 4003, the dif is -50, thus it looks like there's no actual forecast difference when we look at aggregated level. Similarly, for item 1 the dif in absolute value is 300. Other measures we might want to calculate here are Underestimated Forecast (sum of dif values under 0) and Overestimated Forecast (sum of dif values over 0)

VendorFilter.PNG

 

 Here is the pbix sample file. 

https://www.dropbox.com/s/vjphc7h4fftqs1k/ReceptionNo.pbix?dl=0

 

Thank you for taking the time to read this. 🙂 

1 ACCEPTED SOLUTION
v-cherch-msft
Employee
Employee

Hi @Anonymous

 

Please check if below measures match your request.Attached the file for your reference.

PurchasesQuantity =
CALCULATE (
    SUM ( Purchases[Quantity] ),
    FILTER (
        'Purchases',
        Purchases[Reception No] IN VALUES ( 'Purchases Forecast'[Reception No] )
    )
)
ForecastQuantity =
CALCULATE (
    SUM ( 'Purchases Forecast'[Forecast Quantity] ),
    USERELATIONSHIP ( 'Purchases Forecast'[Item], 'Item'[Item No] )
)
Diff =
SUMX (
    Purchases,
    ABS ( 'Purchases Forecast'[ForecastQuantity] - Purchases[PurchasesQuantity] )
)

Regards,

Cherie

Community Support Team _ Cherie Chen
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-cherch-msft
Employee
Employee

Hi @Anonymous

 

Please check if below measures match your request.Attached the file for your reference.

PurchasesQuantity =
CALCULATE (
    SUM ( Purchases[Quantity] ),
    FILTER (
        'Purchases',
        Purchases[Reception No] IN VALUES ( 'Purchases Forecast'[Reception No] )
    )
)
ForecastQuantity =
CALCULATE (
    SUM ( 'Purchases Forecast'[Forecast Quantity] ),
    USERELATIONSHIP ( 'Purchases Forecast'[Item], 'Item'[Item No] )
)
Diff =
SUMX (
    Purchases,
    ABS ( 'Purchases Forecast'[ForecastQuantity] - Purchases[PurchasesQuantity] )
)

Regards,

Cherie

Community Support Team _ Cherie Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you Cherie. This helped me write the correct measure to filter one table based upon values in a second table!

Sorry to post on an old thread, but i'm using a similar dax formula.  Whilst working while, it is very slow - around 22000ms.

 

Calculate (
    Sum(Deals[Value]),
    USERELATIONSHIP('Date'[Date],deals[Add_Time_Local]),
    USERELATIONSHIP(activities[assigned_to_user_id],Pipedrive_Users[id]),
    CROSSFILTER(activities[deal_id],deals[id],Both),
    Filter(deals,deals[id] In VALUES(activities[deal_id])),
    NOT(deals[status]="deleted"

)

    )

For context, the activities table is circa 450k rows and deals table circa 80k rows.  One deal can be multi activties.

 

The formula is looking where an activtiy existing, what is the deal value.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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