Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
Check it out now!Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hello Power BI users. I am trying to create a measurement that gives me the top 10 providers experiencing patient's leaving against staff advice (ASA). The date that I am trying to create this measure lives in two separate tables from two different sources. I've connected these two tables using a date table to connect the two tables.
In the ASA_Ali_1 table there are multiple programs with dates listed within each row. These dates include program capacity which will need to be used in the calculation. (of note, the ASA_Ali_1 table does not contain case by case basis information but a summation of ASAs that have occurred for each date corresponding to a specific program). In the CLEAN_ASA table, contains case by case i.e., client leaving ASA and the provider that was working with said client at the time of their departure.
I need to use the program capacity to generate a relative number of ASAs of a specific provider (contained in CLEAN_ASA) against the average program capacity (contained in ASA_Ali_1). I would like the output to show me the top 10 providers experiencing ASAs for the most recent month.
Here is an image of the two data sources being used so you can get an idea of the structure.
To summarize, my columns, in report view (with the table visualization), should show the provider, the number of ASAs they have experienced in the most recent month, and the percentage of ASAs relative to that program-capacity that provider was working in for the most recent month. (please note that the providers program they are assigned to work [within the CLEAN_ASA table] is titled, "Housing location," and in Ali_ASA_1 this is identified as "Program"). Some of the program names are identified someone differently therefore a mapping table may have to be made.
Solved! Go to Solution.
Hi @eli_dylan ,
If I understand you wrongly, please provide simple data and show the expected results in a picture.
The Table data is shown below:
Please follow these steps:
1.Use the following DAX expression to create a date table
Date =
ADDCOLUMNS (
CALENDAR (
MIN ( MIN ( 'ASA_ALI_1'[Date] ), MIN ( 'CLEAN_ASA'[Date of AS] ) ),
MAX ( MAX ( 'ASA_ALI_1'[Date] ), MAX ( 'CLEAN_ASA'[Date of AS] ) )
),
"Year-Month",
YEAR ( [Date] ) & "-"
& MONTH ( [Date] )
)
2. Use the following DAX expression to create a column in table 'CLEAN_ASA'
Program =
SWITCH(TRUE(),
[Housing location] = "SC Bridges","SC Bridges",
[Housing location] = "AC st.Lucy's","AC SL"
)
3.Use the following DAX expression to create measures
Number of ASAs = COUNT(CLEAN_ASA[Date of AS])
percentage of ASAs =
VAR _Program = SELECTEDVALUE(CLEAN_ASA[Program])
VAR _Capacity = CALCULATE(SUM(ASA_ALI_1[Capacity]),'ASA_ALI_1'[Program] = _Program)
RETURN DIVIDE([Number of ASAs],_Capacity)
4.Final output
Best Regards,
Wenbin Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @eli_dylan ,
If I understand you wrongly, please provide simple data and show the expected results in a picture.
The Table data is shown below:
Please follow these steps:
1.Use the following DAX expression to create a date table
Date =
ADDCOLUMNS (
CALENDAR (
MIN ( MIN ( 'ASA_ALI_1'[Date] ), MIN ( 'CLEAN_ASA'[Date of AS] ) ),
MAX ( MAX ( 'ASA_ALI_1'[Date] ), MAX ( 'CLEAN_ASA'[Date of AS] ) )
),
"Year-Month",
YEAR ( [Date] ) & "-"
& MONTH ( [Date] )
)
2. Use the following DAX expression to create a column in table 'CLEAN_ASA'
Program =
SWITCH(TRUE(),
[Housing location] = "SC Bridges","SC Bridges",
[Housing location] = "AC st.Lucy's","AC SL"
)
3.Use the following DAX expression to create measures
Number of ASAs = COUNT(CLEAN_ASA[Date of AS])
percentage of ASAs =
VAR _Program = SELECTEDVALUE(CLEAN_ASA[Program])
VAR _Capacity = CALCULATE(SUM(ASA_ALI_1[Capacity]),'ASA_ALI_1'[Program] = _Program)
RETURN DIVIDE([Number of ASAs],_Capacity)
4.Final output
Best Regards,
Wenbin Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
This is perfect, thank you so much!!