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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

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

4 REPLIES 4
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
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

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

Top Kudoed Authors