Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
I'm working to put together a stacked column and line chart to show our delinquent loans over the past few months to show the impact of COVID on our loan portfolio.
On the x-axis is a date range.
The columns are grouped by the delinquency stage (30 days, 60 days, 90 days, 120 days). The visual filters out the loans that are not delinquent.
I want the line to show the percentage of deliquent loans compared to the total loan portfolio. The issue I'm having is that the visual is filtering out the non-delinquent loans.
Basically the formula would be (30 days + 60 days + 90 days + 120 days) / (30 days + 60 days + 90 days + 120 days + non-deliquent). But not sure how to do this in DAX?
Below is a mockup of what I'm looking to do. I plan on only doing 1 line, so please ignore the 2 lines.
Any ideas?
Solved! Go to Solution.
Hi, @Anonymous
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Table:
Calendar(a calculated table):
Calendar = CALENDARAUTO()
There is no relationship between two tables. You may create measures like below.
0-30 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="0-30 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
30-60 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="30-60 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
60-90 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="60-90 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
90-120 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="90-120 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
Greater than 120 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="greater than 120 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
Non-delinquent loans =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="non-delinquent loans"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
Percentage = 1-[Non-delinquent loans]
Finally you may use the relative date filter to filter out the specific date range. And then it will display the percentages for each day in the date range.
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @Anonymous
If you take the answer of someone, please mark it as the solution to help the other members who have same problems find it more quickly. If not, let me know and I'll try to help you further. Thanks.
Best Regards
Allan
Hi, @Anonymous
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Table:
Calendar(a calculated table):
Calendar = CALENDARAUTO()
There is no relationship between two tables. You may create measures like below.
0-30 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="0-30 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
30-60 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="30-60 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
60-90 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="60-90 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
90-120 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="90-120 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
Greater than 120 days =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="greater than 120 days"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
Non-delinquent loans =
var _date = SELECTEDVALUE('Calendar'[Date])
var tab =
ADDCOLUMNS(
ALLSELECTED('Table'),
"Flag",
var _datediff = DATEDIFF('Table'[DueDate],_date,DAY)
return
SWITCH(
TRUE(),
_datediff<=0,"non-delinquent loans",
_datediff>0&&_datediff<=30,"0-30 days",
_datediff>30&&_datediff<=60,"30-60 days",
_datediff>60&&_datediff<=90,"60-90 days",
_datediff>90&&_datediff<120,"90-120 days",
"greater than 120 days"
)
)
return
DIVIDE(
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
FILTER(
tab,
[Flag]="non-delinquent loans"
)
),
CALCULATE(
DISTINCTCOUNT('Table'[ID]),
ALL('Table')
)
)
Percentage = 1-[Non-delinquent loans]
Finally you may use the relative date filter to filter out the specific date range. And then it will display the percentages for each day in the date range.
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Check out the April 2025 Power BI update to learn about new features.
Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
User | Count |
---|---|
93 | |
60 | |
44 | |
35 | |
34 |