Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi. I have a data table that looks like this where a new row is created every time the user updated their happiness level:
UserID | Happiness Level | DateUpdated |
1 | 5 | 12/17/19 |
2 | 6 | 12/17/19 |
3 | 3 | 12/17/19 |
4 | 4 | 12/18/19 |
5 | 8 | 12/18/19 |
1 | 7 | 12/20/19 |
1 | 7 | 1/16/20 |
2 | 2 | 1/16/20 |
3 | 3 | 1/16/20 |
3 | 9 | 1/18/20 |
4 | 7 | 1/17/20 |
5 | 9 | 1/17/20 |
I want to average the happiness level of a cohort on the 30th day AFTER their first(MIN) report (so, cohort of USER IDs 1, 2, and 3 average on 1/16/20 and user ID 4 and 5 on 1/17/20.) Only the 30th day after each cohort so I wind up with a table like this:
start date | first happiness avg | 30 days later happiness acg |
1/17/19 | # | # |
1/18/19 | # | # |
I used this to get the initial (MIN) avg happiness level, but cannot figure out how to calculate the same thing 30 days after the MIN. Can you please help?
OTP2 = SUMX ( DISTINCT ( DelOrder[OrderLineID] ); VAR firstArrivalDate = CALCULATE ( MIN ( DelOrder[Orderline Arrival Date] ) ) RETURN CALCULATE ( SUM ( DelOrder[On Time] ); FILTER ( DelOrder; DelOrder[Orderline Arrival Date] = firstArrivalDate ) ) ) / DISTINCTCOUNT ( DelOrder[OrderLineID] )
Hi @Anonymous ,
Could you tell me if your problem has been solved? If it is, kindly mark the helpful answer as a solution if you feel that makes sense. Welcome to share your own solution. More people will benefit from here.
Best Regards,
Xue Ding
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
This problem has not been solved
Hi @Anonymous ,
I create two formulas based on your description and formula. Please try and check if it is what you want. If it is not, please share your expected results. Then we will understand clearly and solve it quickly.
Start date = CALCULATE(MIN('Table'[DateUpdated]),ALLEXCEPT('Table','Table'[UserID]))
Happiness Avg =
VAR total_level =
CALCULATE (
SUM ( 'Table'[Happiness Level] ),
FILTER ( 'Table', 'Table'[DateUpdated] = [Start date] )
)
VAR count_id =
DISTINCTCOUNT ( 'Table'[UserID] )
RETURN
DIVIDE ( total_level, count_id )
30 days later Happiness Avg =
VAR total_level =
CALCULATE (
SUM ( 'Table'[Happiness Level] ),
FILTER (
'Table',
'Table'[DateUpdated] >= [Start date]
&& 'Table'[DateUpdated] <= [Start date] + 30
)
)
VAR count_id =
DISTINCTCOUNT ( 'Table'[UserID] )
RETURN
DIVIDE ( total_level, count_id )
Please see the attachment below.
Best Regards,
Xue Ding
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
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 |
---|---|
106 | |
46 | |
23 | |
23 | |
21 |