Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
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"?
Solved! Go to Solution.
@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
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] )
)
)
)
Proud to be a Super User!
New Animated Dashboard: Sales Calendar
Excel worksheet formulae are power enough to handle it with ease.
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! |
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! |
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:
@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
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] )
)
)
)
Proud to be a Super User!
New Animated Dashboard: Sales Calendar
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.