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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Earliest date for which the count of ingredients with cost <>0, per product, is max

Hello!

 

I have a table with the cost of ingredients, per product, per date. I want to see (for example in a Card), what is the first/oldest date for which the product that I select has the complete costing.

 

Taking the example below:

- Product A: 1/1/2021
- Product B: 1/11/2019

 

ProductIngredientCostDate
Ax51/1/2021
Ay51/1/2021
Ax21/1/2021
Ay 1/12/2020
Bz 1/10/2019
Bz31/11/2019

 

I was thinking something like: the minimum date when count distinct ingredients per product (with cost <>0) = max count distinct ingredients per product (with cost <>0). I have searched everywhere and tried so many different formulas and I cannot find the answer.

Thanks a lot!!!

1 ACCEPTED SOLUTION

@Anonymous If you have a cost of 0 you could do this:

Measure = 
    VAR __Table = SUMMARIZE('Table',[Date],[Ingredient],"__Cost",SUM('Table'[Cost]))
    VAR __Table1 = ADDCOLUMNS(DISTINCT(SELECTCOLUMNS(__Table,"__Date",[Date])),"__Count",COUNTROWS(FILTER(__Table,[Date] = [__Date] && ( [__Cost] = BLANK() || [__Cost] = 0 ) )))
RETURN
     MINX(FILTER(__Table1,[__Count] < 1),[__Date])


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

7 REPLIES 7
Greg_Deckler
Community Champion
Community Champion

@Anonymous Try this:

Measure = 
    VAR __Table = SUMMARIZE('Table',[Date],[Ingredient],"__Cost",SUM('Table'[Cost]))
    VAR __Table1 = ADDCOLUMNS(DISTINCT(SELECTCOLUMNS(__Table,"__Date",[Date])),"__Count",COUNTROWS(FILTER(__Table,[Date] = [__Date] && [__Cost] = BLANK())))
RETURN
     MINX(FILTER(__Table1,[__Count] < 1),[__Date])


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

Thanks SO MUCH for your quick and good answer.

 

It works for the majority. But for some products, this appears as blank - how can I fix this?
Could it be because in some cases an ingredient is costed at blank (as in my table example) but in other cases i have the cost as 0? 

Thanks @Greg_Deckler .

 

@Anonymous If you have a cost of 0 you could do this:

Measure = 
    VAR __Table = SUMMARIZE('Table',[Date],[Ingredient],"__Cost",SUM('Table'[Cost]))
    VAR __Table1 = ADDCOLUMNS(DISTINCT(SELECTCOLUMNS(__Table,"__Date",[Date])),"__Count",COUNTROWS(FILTER(__Table,[Date] = [__Date] && ( [__Cost] = BLANK() || [__Cost] = 0 ) )))
RETURN
     MINX(FILTER(__Table1,[__Count] < 1),[__Date])


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

I think that's perfect. Thank you!

I have a slicer with the dates, would it be possible to make the first date displayed in the slicer = to this measure we just calculated (and not show any earlier date than that)?

Thank you

@Anonymous To quote old Roblox, "Ooof", defaulting slicers to things is not really a thing.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

Thanks for the update.

Anonymous
Not applicable

Hi @Anonymous ,

You can create two measures as below to get it, please find the details in the attachment.

Measure = SUM('Table'[Cost])
Min Date = 
VAR _selpro =
    SELECTEDVALUE ( 'Table'[Product] )
RETURN
    CALCULATE (
        MIN ( 'Table'[Date] ),
        FILTER ( ALLSELECTED ( 'Table' ), 'Table'[Product] = _selpro && [Measure] > 0 )
    )

yingyinr_0-1666172620672.png

Best Regards

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.