Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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] )
)
)
)
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.
@ejoyce5 you can use the following two measures to give you whatyou need
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] ) )
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
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?
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] )
)
)
)
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
25 | |
19 | |
18 | |
18 | |
15 |
User | Count |
---|---|
38 | |
20 | |
18 | |
16 | |
10 |