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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
kangx322
Frequent Visitor

Find the first date that hits the goal

I am trying to find the first date that hits the goal (100 in this case) per ID

 

Below is the sample data structure and desired output

 

What would be the DAX Formula for calculating the "First Date to hit the goal"?

 

kangx322_0-1634932023112.png

 

1 ACCEPTED SOLUTION
smpa01
Super User
Super User

@kangx322  if you have a table (called 'fact')  like this 

 

 

| id | date       | value |
|----|------------|-------|
| 1  | 2021-01-01 | 20    |
| 1  | 2021-01-01 | 30    |
| 1  | 2021-01-02 | 70    |
| 1  | 2021-01-02 | 40    |
| 1  | 2021-01-03 | 80    |
| 1  | 2021-01-03 | 90    |
| 2  | 2021-01-01 | 80    |
| 2  | 2021-01-02 | 40    |
| 2  | 2021-01-03 | 70    |
| 2  | 2021-01-03 | 60    |
| 2  | 2021-01-04 | 130   |

 

 

and desire to come to this

smpa01_0-1634938857687.png

You can write following two measures

 

earliestDayTargetMet = 
CALCULATE (
    MIN ( 'fact'[date] ),
    FILTER (
        'fact',
        'fact'[date]
            = CALCULATE (
                MINX (
                    FILTER (
                        ADDCOLUMNS (
                            'fact',
                            "sum",
                                CALCULATE (
                                    SUM ( 'fact'[value] ),
                                    ALLEXCEPT ( 'fact', 'fact'[id], 'fact'[date] )
                                )
                        ),
                        [sum] >= 100
                    ),
                    'fact'[date]
                ),
                ALLEXCEPT ( 'fact', 'fact'[id] )
            )
    )
)


sumValueOnEarliestDayTargetMet = 
CALCULATE (
    SUM ( 'fact'[value] ),
    FILTER (
        'fact',
        'fact'[date]
            = CALCULATE (
                MINX (
                    FILTER (
                        ADDCOLUMNS (
                            'fact',
                            "sum",
                                CALCULATE (
                                    SUM ( 'fact'[value] ),
                                    ALLEXCEPT ( 'fact', 'fact'[id], 'fact'[date] )
                                )
                        ),
                        [sum] >= 100
                    ),
                    'fact'[date]
                ),
                ALLEXCEPT ( 'fact', 'fact'[id] )
            )
    )
)

 

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

View solution in original post

9 REPLIES 9
ejoyce5
Frequent Visitor

I'm trying to do a similar situation but need to display 1 row for each ID that has hit the $200 threshold. The output needs to have 1 row for each ID, the first date (min) date the ID hit that threshold, and then a running $ total -- even if the ID hits the threshold multiple times, I just want the first date and the entire sum of that ID for a time period. I am having issues with displaying the min date if ID's have multiple check IDs that hit the $200 threshold alone. 

 

Screenshot 2024-07-11 at 11.00.45 AM.png

@ejoyce5  you can use the following two measures to give you whatyou need

 

smpa01_1-1720714279768.png

 

 

 

 

 

runningTotal = 
VAR runningTotal =
    CALCULATE (
        SUM ( t1[Paid] ),
        WINDOW (
            1,
            ABS,
            0,
            REL,
            ALL ( t1[ID], t1[Date] ),
            ORDERBY ( t1[Date], ASC ),
            ,
            PARTITIONBY ( t1[ID] )
        ),
        ALL ( t1 )
    )
return runningTotal 


minDate = 
VAR mxID =
    MAX ( t1[ID] )
VAR cond =
    CALCULATE (
        MIN ( t1[Date] ),
        TOPN (
            1,
            FILTER ( ALL ( t1 ), t1[ID] = mxID && [runningTotal] >= 200 ),
            t1[Date], ASC
        )
    )
RETURN
    IF ( MAX ( t1[Date] ) == cond, MAX ( t1[Date] ) )

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Thanks @smpa01 , but when I do that it returns the max date for each ID, not the MIN date of when the running total hit > $200. For ex: in my example above, the ID 1 hit > $200 threshold 1/3/2024 and had another check 2/2/2024 too which increases the running total, but the only thing I care about is the MIN date of when an ID hit the threshold and then display the running total overall (say the date is through 6/1/2024, and the ID hit > $200 threshold 1/3/2024 I would want to see the ID, date 1/3/2024, and the running total as of 6/1/2024. 

@ejoyce5 refer to the attached pbix

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Thank you, this resolved my issue and I was able to solve. Curious - is there a way to get count of rows in the visual, or number of distinct IDs in the visual on the total bar? Or another way to visualize in a metric form of total number of rows in this output?

CNENFRNL
Community Champion
Community Champion

Excel worksheet formulae are power enough to handle it with ease.

Screenshot 2021-10-23 142858.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

CNENFRNL
Community Champion
Community Champion

Screenshot 2021-10-23 105247.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Anonymous
Not applicable

Hello @CNENFRNL .
I had the exact same problem, with the same kind of table/columns, and your solution worked fine for me.
The only difference is that the Target is set to 100 (fixed) and not Max(Target[target])
The problem is that i want the earliest date as a column, in order to use it as a filter or in the x-axis of a line chart. 
When i use your DAX in a calculated column i get the following error message "a circular dependency was detected".

The exact DAX i use for the calculated column is the following:

earliest_date_correct_column =
var tgt=100
return
minx(
filter(
values(Sales[date]),
CALCULATE(sum(Sales[value]), Sales[date]<= earlier ( Sales[date]))>= tgt),
Sales[date])

Could you please help me fix it? I'm really stuck. 
Thanks in advance
Kostas
smpa01
Super User
Super User

@kangx322  if you have a table (called 'fact')  like this 

 

 

| id | date       | value |
|----|------------|-------|
| 1  | 2021-01-01 | 20    |
| 1  | 2021-01-01 | 30    |
| 1  | 2021-01-02 | 70    |
| 1  | 2021-01-02 | 40    |
| 1  | 2021-01-03 | 80    |
| 1  | 2021-01-03 | 90    |
| 2  | 2021-01-01 | 80    |
| 2  | 2021-01-02 | 40    |
| 2  | 2021-01-03 | 70    |
| 2  | 2021-01-03 | 60    |
| 2  | 2021-01-04 | 130   |

 

 

and desire to come to this

smpa01_0-1634938857687.png

You can write following two measures

 

earliestDayTargetMet = 
CALCULATE (
    MIN ( 'fact'[date] ),
    FILTER (
        'fact',
        'fact'[date]
            = CALCULATE (
                MINX (
                    FILTER (
                        ADDCOLUMNS (
                            'fact',
                            "sum",
                                CALCULATE (
                                    SUM ( 'fact'[value] ),
                                    ALLEXCEPT ( 'fact', 'fact'[id], 'fact'[date] )
                                )
                        ),
                        [sum] >= 100
                    ),
                    'fact'[date]
                ),
                ALLEXCEPT ( 'fact', 'fact'[id] )
            )
    )
)


sumValueOnEarliestDayTargetMet = 
CALCULATE (
    SUM ( 'fact'[value] ),
    FILTER (
        'fact',
        'fact'[date]
            = CALCULATE (
                MINX (
                    FILTER (
                        ADDCOLUMNS (
                            'fact',
                            "sum",
                                CALCULATE (
                                    SUM ( 'fact'[value] ),
                                    ALLEXCEPT ( 'fact', 'fact'[id], 'fact'[date] )
                                )
                        ),
                        [sum] >= 100
                    ),
                    'fact'[date]
                ),
                ALLEXCEPT ( 'fact', 'fact'[id] )
            )
    )
)

 

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

November Carousel

Fabric Community Update - November 2024

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

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.