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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
PhoenixBird66
Helper III
Helper III

firstnonblank or MAX - measure to return the first value in a column based on another column

I'm having real problems writing a measure to return the first value in a column based on whether another column is blank or not.

 

I have 2 tables - Price History and Sales. They are joined by a one to many relationship based on a key (a concatentation of service code & unit price.).

 

I want to write a measure that will return the first (as in earliest) value where the Quantity Sold is not blank for each part (or StdSvcKey). So in the case below the number I want for this part is £621.86.

 

Capture.PNG

 

 

 

 

 

 

 

I've tried 2 different methods so far but they dont do what i want.

 

I tried:

 

= FIRSTNONBLANK(PRICEHISTORY[Unit Price],0)
 
But this retruned the value £0.01
 
I also tried adding a caluclated column (DaysSincePriceChanged) to give me the number of days since the start date of the price change, so that I could then use MAX:
 
  CALCULATE(
   MAX( PRICEHISTORY [Unit Price]),
   KEEPFILTERS(
FILTER(
       PRICEHISTORY ,
   PRICEHISTORY [DaysSincePriceChanged] = CALCULATE(MAX(PRICEHISTORY [DaysSincePriceChanged]), ALLEXCEPT(PRICEHISTORY , PRICEHISTORY [StdSvcKey]))
     )
   ),
   ALLEXCEPT(PRICEHISTORY ,  PRICEHISTORY [StdSvcKey])
)
 
but this returns a value of £604.80, so thats not right either.
 
Any ideas guys?
2 ACCEPTED SOLUTIONS

Hi @PhoenixBird66 ,

 

Please try this formula below, which is more intuitive. 

 

Measure 2 =
MINX (
    TOPN (
        1,
        FILTER ( 'Table1', 'Table1'[Quantity Sold] <> BLANK () ),
        Table1[Start Date], ASC
    ),
    [Unit Price]
)

 

 

 

Best Regards,

Community Support Team _ Dale
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

Hi @PhoenixBird66 ,

 

Could you please mark the proper answers as solutions?

 

 

Best Regards,

Community Support Team _ Dale
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

5 REPLIES 5
v-jiascu-msft
Employee
Employee

Hi @PhoenixBird66 ,

 

Try this simpler one. The key point here is the row context that we need to convert.

Measure =
FIRSTNONBLANK (
    Table1[Unit Price],
    CALCULATE ( SUM ( Table1[Quantity Sold] ) )
)

firstnonblank-or-MAX-measure-to-return-the-first-value-in-a-column-based-on-another-column

Best Regards,

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

Thanks for your response.

 

I've tried this but it seems to be picking up the first (as in smallest) value rather than the first (as in oldest value). So in this example it returns the value £25.12, but I want it to return the value £26.00.

 

I need it to return the OLDEST unit price (based on the Start Date column) where the Quantity Sold is not blank or zero.

 

Capture.PNG

Hi @PhoenixBird66 ,

 

Could you please mark the proper answers as solutions?

 

 

Best Regards,

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

Hi @PhoenixBird66 ,

 

Please try this formula below, which is more intuitive. 

 

Measure 2 =
MINX (
    TOPN (
        1,
        FILTER ( 'Table1', 'Table1'[Quantity Sold] <> BLANK () ),
        Table1[Start Date], ASC
    ),
    [Unit Price]
)

 

 

 

Best Regards,

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

hi,

 

this might be happening because you have some page filter on.

 

please see the link below, this will give you a clear understanding

 

Link

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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