cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mscottsewell
Microsoft
Microsoft

DAX Question - Return first date value from a filtered, secondary related table

I’m struggling with a DAX query/concept –

 

I have three Entities that have relationships between them: (Account 1:M Opportunity 1:M Opportuntity Lines)

 

I’m trying to accomplish the same thing in DAX as I would in SQL –

SELECT A.name, OL.productline, MAX(O.createdon) [Oldest AX Opportunity]
FROM dbo.account A
LEFT OUTER JOIN dbo.opportunity AS O     
        ON O.accountid = A.accountid
LEFT OUTER JOIN dbo.opportunitylineitem AS OL   
        ON OL.opportunityid = O.opportunityid
WHERE OL.productline = 'AX'
GROUP BY A.name, OL.productline;

 

 

My first attempt to replicate this in DAX was:

  1. Created a new column on the Opportunity entity to return a True() if a Opportunity Line Item = “AX” existed. 
    (This works correctly and I’m using it for other elements in the report)
    Includes AX = 
    NOT ISEMPTY (
        CALCULATETABLE (
            'Opportunity Line Items',
            'Opportunity Line Items'[Product Line] = "AX"
        )
    )
  2. Then, on the Account entity, I added a new Column to return the first date where the ‘Opportunity’[Includes AX] = TRUE()
    1. The first version returned the earliest date in the Opportunity table (regardless of the Account)
      Oldest AX Opportunity =
      CALCULATE (
          FIRSTDATE ( Opportunities[Created On] ),
          FILTER (
              Opportunities,
              Opportunities[Includes AX] = TRUE ()
          )
      )
    2. I added an Account Filter hoping that would limit the opportunities to just the account I’m on.
      Oldest AX Opportunity =
      CALCULATE (
          FIRSTDATE ( Opportunities[Created On] ),
          FILTER (
              Opportunities,
              Opportunities[Includes AX] = TRUE ()
                  && Opportunities[Account (Value)] = Account[AccountId]
          )
      )
      However I get this error when I attempt to use it:
      <!> Column '' in Table '' contains blank values and this is not allowed for columns on the one side of a many-to-one relationship or for columns that are used as the primary key of a table.
      (Just as a test, I tried removing the “Opportunities[Includes AX] = TRUE()” condition from this version and it did return the oldest opportunity for that Account, however I need it filtered by Product Line.)

I've a explored couple of dozen questions/soluions here and I've read and re-read the post from SQL BI on Context Translation but I don't seem to be connecting the dots on where my approach to the query is going wrong.  (I won't bore you with the multiple variations of nesting 'Calculate' or Filters that I've tried without success.)

 

Any suggestions on where to revise my thinking on this?

 

Thanks,
Scott.

1 ACCEPTED SOLUTION
mscottsewell
Microsoft
Microsoft

The formula is actually working - however at some point with earlier tests, the column on my table (apparently) became corrupt and almost no formula would resolve without throwing an error -
The solution was to delete the column and paste the identical code (from 2.2) into a new column.

That's three hours of my life I won't get back... Smiley Frustrated

 

A colleague, Jarid Mckenzie,  suggested this alternative / improvement which should avoid some other challenges in later iterations, but so far both versions are working for me.

First Op = 
CALCULATE (
    MIN ( Opportunities[Created On] ),
    FILTER (
        ALL ( Opportunities ),
        Opportunities[Account (Value)] = EARLIER ( Account[AccountId] )
            && Opportunities[Includes AX]
    )
)

 

View solution in original post

3 REPLIES 3
mscottsewell
Microsoft
Microsoft

The formula is actually working - however at some point with earlier tests, the column on my table (apparently) became corrupt and almost no formula would resolve without throwing an error -
The solution was to delete the column and paste the identical code (from 2.2) into a new column.

That's three hours of my life I won't get back... Smiley Frustrated

 

A colleague, Jarid Mckenzie,  suggested this alternative / improvement which should avoid some other challenges in later iterations, but so far both versions are working for me.

First Op = 
CALCULATE (
    MIN ( Opportunities[Created On] ),
    FILTER (
        ALL ( Opportunities ),
        Opportunities[Account (Value)] = EARLIER ( Account[AccountId] )
            && Opportunities[Includes AX]
    )
)

 

How would I retrieve a name based on this earliest date ? This column would only calculate the earliest date. I'm basically trying to do any "order by" on a date field, and get the corresponding Name. Any thoughts on how your query below could be tweaked to achieve that In that column 

But How do you actually get the Name in that column. 

 

First Op = 
CALCULATE (
    MIN ( Opportunities[Created On] ),
    FILTER (
        ALL ( Opportunities ),
        Opportunities[Account (Value)] = EARLIER ( Account[AccountId] )
            && Opportunities[Includes AX]
    )
)

This gets you the earliest date. I'm trying to retrieve the Name field of that Earliest opportunity. Any thoughts on how i could do that ?

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

Thank you 2022 Review

2022 Monthly Feature Releases

We had a great 2022 with a ton of feature releases to help you drive a data culture.