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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

TRICKY DAX Calculated Column Measures

Hi Experts

 

Need to add the following as calcaluated column measure into my pbix file (see images below) i am trying to populate columns I, J and k into my pbix file. The formulas used in excel are shown below.

 

Sample file. 

link: https://www.dropbox.com/s/47fyhkj5euzw02q/Kaplan_Miers_v1.2.pbix?dl=0

 

Capture.PNG

 

1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

Hey @Anonymous , I received a request regarding confidence intervals with Kaplan Meier survival curves from @Anonymous and so I was working on it and came up with the following answer:

 

OK, following along from this:

http://www.real-statistics.com/survival-analysis/kaplan-meier-procedure/confidence-interval-for-the-...

 

And if you are following my article here:

https://community.powerbi.com/t5/Community-Blog/Kaplan-Meier-Survival-Curves-with-Power-BI-Part-2/ba...

 

Then in your KMDeptDaysAll table, create this measure:

 

ci_alpha = 0.05

This is your confidence interval, in this case 95%

 

And then create these columns:

 

ci_S(t) = 
VAR __table = FILTER(ALL(KMDeptDaysAll),[Department] = EARLIER([Department]) && [Days] <= EARLIER([Days]))
RETURN
PRODUCTX(__table,[1-e_i/d_i])

ci_se_1 = 
VAR __calc = [e_i] / ([d_i] * ([d_i] - [e_i]))
RETURN
IF(ISERROR(SQRT(__calc)),BLANK(),[ci_S(t)] * SQRT(__calc))

ci_se = 
VAR __table = FILTER(ALL(KMDeptDaysAll),[Department] = EARLIER([Department]) && [Days] <= EARLIER([Days]))
VAR __sum = SUMX(__table,[ci_se_1])
RETURN
[ci_S(t)] * __sum

ci_lower = 
[ci_S(t)] ^ IF(ISERROR(EXP(NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)]))),BLANK(),EXP(NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)])))

ci_upper = 
[ci_S(t)] ^ IF(ISERROR(EXP(-NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)]))),BLANK(),EXP(-NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)])))

Can't be certain this is all 100% correct as the original article I was working from didn't have confidence intervals. Will try to do some verification work on this.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

2 REPLIES 2
Greg_Deckler
Super User
Super User

Hey @Anonymous , I received a request regarding confidence intervals with Kaplan Meier survival curves from @Anonymous and so I was working on it and came up with the following answer:

 

OK, following along from this:

http://www.real-statistics.com/survival-analysis/kaplan-meier-procedure/confidence-interval-for-the-...

 

And if you are following my article here:

https://community.powerbi.com/t5/Community-Blog/Kaplan-Meier-Survival-Curves-with-Power-BI-Part-2/ba...

 

Then in your KMDeptDaysAll table, create this measure:

 

ci_alpha = 0.05

This is your confidence interval, in this case 95%

 

And then create these columns:

 

ci_S(t) = 
VAR __table = FILTER(ALL(KMDeptDaysAll),[Department] = EARLIER([Department]) && [Days] <= EARLIER([Days]))
RETURN
PRODUCTX(__table,[1-e_i/d_i])

ci_se_1 = 
VAR __calc = [e_i] / ([d_i] * ([d_i] - [e_i]))
RETURN
IF(ISERROR(SQRT(__calc)),BLANK(),[ci_S(t)] * SQRT(__calc))

ci_se = 
VAR __table = FILTER(ALL(KMDeptDaysAll),[Department] = EARLIER([Department]) && [Days] <= EARLIER([Days]))
VAR __sum = SUMX(__table,[ci_se_1])
RETURN
[ci_S(t)] * __sum

ci_lower = 
[ci_S(t)] ^ IF(ISERROR(EXP(NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)]))),BLANK(),EXP(NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)])))

ci_upper = 
[ci_S(t)] ^ IF(ISERROR(EXP(-NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)]))),BLANK(),EXP(-NORM.S.INV([ci_alpha]/2)/IF(ISERROR(LN([ci_S(t)])),BLANK(),LN([ci_S(t)])*[ci_se]/[ci_S(t)])))

Can't be certain this is all 100% correct as the original article I was working from didn't have confidence intervals. Will try to do some verification work on this.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
v-xuding-msft
Community Support
Community Support

Hi @Anonymous ,

In your sample, I found  there are some values like negative number and ∞. They cause that the SQRT function returns an error. You could use the function of IF to handle them firstly. 

 

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.

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.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors